blob: 28b66b2c374945a31f56a43b2c92d2fd032a8326 [file] [log] [blame]
drhd62c0f42015-04-09 13:34:29 +00001/*
2** 2015-04-06
3**
4** The author disclaims copyright to this source code. In place of
5** a legal notice, here is a blessing:
6**
7** May you do good and not evil.
8** May you find forgiveness for yourself and forgive others.
9** May you share freely, never taking more than you give.
10**
11*************************************************************************
12**
13** This is a utility problem that computes the differences in content
14** between two SQLite databases.
15*/
16#include <stdio.h>
17#include <stdlib.h>
18#include <stdarg.h>
19#include <ctype.h>
20#include <string.h>
21#include "sqlite3.h"
22
23/*
24** All global variables are gathered into the "g" singleton.
25*/
26struct GlobalVars {
27 const char *zArgv0; /* Name of program */
28 int bSchemaOnly; /* Only show schema differences */
drha37591c2015-04-09 18:14:03 +000029 int bSchemaPK; /* Use the schema-defined PK, not the true PK */
drhd62c0f42015-04-09 13:34:29 +000030 unsigned fDebug; /* Debug flags */
31 sqlite3 *db; /* The database connection */
32} g;
33
34/*
35** Allowed values for g.fDebug
36*/
37#define DEBUG_COLUMN_NAMES 0x000001
38#define DEBUG_DIFF_SQL 0x000002
39
40/*
41** Dynamic string object
42*/
43typedef struct Str Str;
44struct Str {
45 char *z; /* Text of the string */
46 int nAlloc; /* Bytes allocated in z[] */
47 int nUsed; /* Bytes actually used in z[] */
48};
49
50/*
51** Initialize a Str object
52*/
53static void strInit(Str *p){
54 p->z = 0;
55 p->nAlloc = 0;
56 p->nUsed = 0;
57}
58
59/*
60** Print an error resulting from faulting command-line arguments and
61** abort the program.
62*/
63static void cmdlineError(const char *zFormat, ...){
64 va_list ap;
65 fprintf(stderr, "%s: ", g.zArgv0);
66 va_start(ap, zFormat);
67 vfprintf(stderr, zFormat, ap);
68 va_end(ap);
69 fprintf(stderr, "\n\"%s --help\" for more help\n", g.zArgv0);
70 exit(1);
71}
72
73/*
74** Print an error message for an error that occurs at runtime, then
75** abort the program.
76*/
77static void runtimeError(const char *zFormat, ...){
78 va_list ap;
79 fprintf(stderr, "%s: ", g.zArgv0);
80 va_start(ap, zFormat);
81 vfprintf(stderr, zFormat, ap);
82 va_end(ap);
83 fprintf(stderr, "\n");
84 exit(1);
85}
86
87/*
88** Free all memory held by a Str object
89*/
90static void strFree(Str *p){
91 sqlite3_free(p->z);
92 strInit(p);
93}
94
95/*
96** Add formatted text to the end of a Str object
97*/
98static void strPrintf(Str *p, const char *zFormat, ...){
99 int nNew;
100 for(;;){
101 if( p->z ){
102 va_list ap;
103 va_start(ap, zFormat);
104 sqlite3_vsnprintf(p->nAlloc-p->nUsed, p->z+p->nUsed, zFormat, ap);
105 va_end(ap);
106 nNew = (int)strlen(p->z + p->nUsed);
107 }else{
108 nNew = p->nAlloc;
109 }
110 if( p->nUsed+nNew < p->nAlloc-1 ){
111 p->nUsed += nNew;
112 break;
113 }
114 p->nAlloc = p->nAlloc*2 + 1000;
115 p->z = sqlite3_realloc(p->z, p->nAlloc);
116 if( p->z==0 ) runtimeError("out of memory");
117 }
118}
119
120
121
122/* Safely quote an SQL identifier. Use the minimum amount of transformation
123** necessary to allow the string to be used with %s.
124**
125** Space to hold the returned string is obtained from sqlite3_malloc(). The
126** caller is responsible for ensuring this space is freed when no longer
127** needed.
128*/
129static char *safeId(const char *zId){
130 /* All SQLite keywords, in alphabetical order */
131 static const char *azKeywords[] = {
132 "ABORT", "ACTION", "ADD", "AFTER", "ALL", "ALTER", "ANALYZE", "AND", "AS",
133 "ASC", "ATTACH", "AUTOINCREMENT", "BEFORE", "BEGIN", "BETWEEN", "BY",
134 "CASCADE", "CASE", "CAST", "CHECK", "COLLATE", "COLUMN", "COMMIT",
135 "CONFLICT", "CONSTRAINT", "CREATE", "CROSS", "CURRENT_DATE",
136 "CURRENT_TIME", "CURRENT_TIMESTAMP", "DATABASE", "DEFAULT", "DEFERRABLE",
137 "DEFERRED", "DELETE", "DESC", "DETACH", "DISTINCT", "DROP", "EACH",
138 "ELSE", "END", "ESCAPE", "EXCEPT", "EXCLUSIVE", "EXISTS", "EXPLAIN",
139 "FAIL", "FOR", "FOREIGN", "FROM", "FULL", "GLOB", "GROUP", "HAVING", "IF",
140 "IGNORE", "IMMEDIATE", "IN", "INDEX", "INDEXED", "INITIALLY", "INNER",
141 "INSERT", "INSTEAD", "INTERSECT", "INTO", "IS", "ISNULL", "JOIN", "KEY",
142 "LEFT", "LIKE", "LIMIT", "MATCH", "NATURAL", "NO", "NOT", "NOTNULL",
143 "NULL", "OF", "OFFSET", "ON", "OR", "ORDER", "OUTER", "PLAN", "PRAGMA",
144 "PRIMARY", "QUERY", "RAISE", "RECURSIVE", "REFERENCES", "REGEXP",
145 "REINDEX", "RELEASE", "RENAME", "REPLACE", "RESTRICT", "RIGHT",
146 "ROLLBACK", "ROW", "SAVEPOINT", "SELECT", "SET", "TABLE", "TEMP",
147 "TEMPORARY", "THEN", "TO", "TRANSACTION", "TRIGGER", "UNION", "UNIQUE",
148 "UPDATE", "USING", "VACUUM", "VALUES", "VIEW", "VIRTUAL", "WHEN", "WHERE",
149 "WITH", "WITHOUT",
150 };
151 int lwr, upr, mid, c, i, x;
152 for(i=x=0; (c = zId[i])!=0; i++){
153 if( !isalpha(c) && c!='_' ){
154 if( i>0 && isdigit(c) ){
155 x++;
156 }else{
157 return sqlite3_mprintf("\"%w\"", zId);
158 }
159 }
160 }
161 if( x ) return sqlite3_mprintf("%s", zId);
162 lwr = 0;
163 upr = sizeof(azKeywords)/sizeof(azKeywords[0]) - 1;
164 while( lwr<=upr ){
165 mid = (lwr+upr)/2;
166 c = sqlite3_stricmp(azKeywords[mid], zId);
167 if( c==0 ) return sqlite3_mprintf("\"%w\"", zId);
168 if( c<0 ){
169 lwr = mid+1;
170 }else{
171 upr = mid-1;
172 }
173 }
174 return sqlite3_mprintf("%s", zId);
175}
176
177/*
178** Prepare a new SQL statement. Print an error and abort if anything
179** goes wrong.
180*/
181static sqlite3_stmt *db_vprepare(const char *zFormat, va_list ap){
182 char *zSql;
183 int rc;
184 sqlite3_stmt *pStmt;
185
186 zSql = sqlite3_vmprintf(zFormat, ap);
187 if( zSql==0 ) runtimeError("out of memory");
188 rc = sqlite3_prepare_v2(g.db, zSql, -1, &pStmt, 0);
189 if( rc ){
190 runtimeError("SQL statement error: %s\n\"%s\"", sqlite3_errmsg(g.db),
191 zSql);
192 }
193 sqlite3_free(zSql);
194 return pStmt;
195}
196static sqlite3_stmt *db_prepare(const char *zFormat, ...){
197 va_list ap;
198 sqlite3_stmt *pStmt;
199 va_start(ap, zFormat);
200 pStmt = db_vprepare(zFormat, ap);
201 va_end(ap);
202 return pStmt;
203}
204
205/*
206** Free a list of strings
207*/
208static void namelistFree(char **az){
209 if( az ){
210 int i;
211 for(i=0; az[i]; i++) sqlite3_free(az[i]);
212 sqlite3_free(az);
213 }
214}
215
216/*
217** Return a list of column names for the table zDb.zTab. Space to
drh39b355c2015-04-09 13:40:18 +0000218** hold the list is obtained from sqlite3_malloc() and should released
219** using namelistFree() when no longer needed.
drhd62c0f42015-04-09 13:34:29 +0000220**
drha37591c2015-04-09 18:14:03 +0000221** Primary key columns are listed first, followed by data columns.
222** The number of columns in the primary key is returned in *pnPkey.
drhd62c0f42015-04-09 13:34:29 +0000223**
drha37591c2015-04-09 18:14:03 +0000224** Normally, the "primary key" in the previous sentence is the true
225** primary key - the rowid or INTEGER PRIMARY KEY for ordinary tables
226** or the declared PRIMARY KEY for WITHOUT ROWID tables. However, if
227** the g.bSchemaPK flag is set, then the schema-defined PRIMARY KEY is
228** used in all cases. In that case, entries that have NULL values in
229** any of their primary key fields will be excluded from the analysis.
230**
231** If the primary key for a table is the rowid but rowid is inaccessible,
drhd62c0f42015-04-09 13:34:29 +0000232** then this routine returns a NULL pointer.
233**
234** Examples:
235** CREATE TABLE t1(a INT UNIQUE, b INTEGER, c TEXT, PRIMARY KEY(c));
236** *pnPKey = 1;
drha37591c2015-04-09 18:14:03 +0000237** az = { "rowid", "a", "b", "c", 0 } // Normal case
238** az = { "c", "a", "b", 0 } // g.bSchemaPK==1
drhd62c0f42015-04-09 13:34:29 +0000239**
240** CREATE TABLE t2(a INT UNIQUE, b INTEGER, c TEXT, PRIMARY KEY(b));
241** *pnPKey = 1;
242** az = { "b", "a", "c", 0 }
243**
244** CREATE TABLE t3(x,y,z,PRIMARY KEY(y,z));
drha37591c2015-04-09 18:14:03 +0000245** *pnPKey = 1 // Normal case
246** az = { "rowid", "x", "y", "z", 0 } // Normal case
247** *pnPKey = 2 // g.bSchemaPK==1
248** az = { "y", "x", "z", 0 } // g.bSchemaPK==1
drhd62c0f42015-04-09 13:34:29 +0000249**
250** CREATE TABLE t4(x,y,z,PRIMARY KEY(y,z)) WITHOUT ROWID;
251** *pnPKey = 2
252** az = { "y", "z", "x", 0 }
253**
254** CREATE TABLE t5(rowid,_rowid_,oid);
255** az = 0 // The rowid is not accessible
256*/
257static char **columnNames(const char *zDb, const char *zTab, int *pnPKey){
drha37591c2015-04-09 18:14:03 +0000258 char **az = 0; /* List of column names to be returned */
259 int naz = 0; /* Number of entries in az[] */
260 sqlite3_stmt *pStmt; /* SQL statement being run */
drhd62c0f42015-04-09 13:34:29 +0000261 char *zPkIdxName = 0; /* Name of the PRIMARY KEY index */
drha37591c2015-04-09 18:14:03 +0000262 int truePk = 0; /* PRAGMA table_info indentifies the PK to use */
drhd62c0f42015-04-09 13:34:29 +0000263 int nPK = 0; /* Number of PRIMARY KEY columns */
drha37591c2015-04-09 18:14:03 +0000264 int i, j; /* Loop counters */
drhd62c0f42015-04-09 13:34:29 +0000265
drha37591c2015-04-09 18:14:03 +0000266 if( g.bSchemaPK==0 ){
267 /* Normal case: Figure out what the true primary key is for the table.
268 ** * For WITHOUT ROWID tables, the true primary key is the same as
269 ** the schema PRIMARY KEY, which is guaranteed to be present.
270 ** * For rowid tables with an INTEGER PRIMARY KEY, the true primary
271 ** key is the INTEGER PRIMARY KEY.
272 ** * For all other rowid tables, the rowid is the true primary key.
273 */
274 pStmt = db_prepare("PRAGMA %s.index_list=%Q", zDb, zTab);
drhd62c0f42015-04-09 13:34:29 +0000275 while( SQLITE_ROW==sqlite3_step(pStmt) ){
drha37591c2015-04-09 18:14:03 +0000276 if( sqlite3_stricmp((const char*)sqlite3_column_text(pStmt,3),"pk")==0 ){
277 zPkIdxName = sqlite3_mprintf("%s", sqlite3_column_text(pStmt, 1));
278 break;
279 }
drhd62c0f42015-04-09 13:34:29 +0000280 }
281 sqlite3_finalize(pStmt);
drha37591c2015-04-09 18:14:03 +0000282 if( zPkIdxName ){
283 int nKey = 0;
284 int nCol = 0;
285 truePk = 0;
286 pStmt = db_prepare("PRAGMA %s.index_xinfo=%Q", zDb, zPkIdxName);
287 while( SQLITE_ROW==sqlite3_step(pStmt) ){
288 nCol++;
289 if( sqlite3_column_int(pStmt,5) ){ nKey++; continue; }
290 if( sqlite3_column_int(pStmt,1)>=0 ) truePk = 1;
291 }
292 if( nCol==nKey ) truePk = 1;
293 if( truePk ){
294 nPK = nKey;
295 }else{
296 nPK = 1;
297 }
298 sqlite3_finalize(pStmt);
299 sqlite3_free(zPkIdxName);
300 }else{
301 truePk = 1;
302 nPK = 1;
303 }
304 pStmt = db_prepare("PRAGMA %s.table_info=%Q", zDb, zTab);
drhd62c0f42015-04-09 13:34:29 +0000305 }else{
drha37591c2015-04-09 18:14:03 +0000306 /* The g.bSchemaPK==1 case: Use whatever primary key is declared
307 ** in the schema. The "rowid" will still be used as the primary key
308 ** if the table definition does not contain a PRIMARY KEY.
309 */
310 nPK = 0;
311 pStmt = db_prepare("PRAGMA %s.table_info=%Q", zDb, zTab);
312 while( SQLITE_ROW==sqlite3_step(pStmt) ){
313 if( sqlite3_column_int(pStmt,5)>0 ) nPK++;
314 }
315 sqlite3_reset(pStmt);
316 if( nPK==0 ) nPK = 1;
drhd62c0f42015-04-09 13:34:29 +0000317 truePk = 1;
drhd62c0f42015-04-09 13:34:29 +0000318 }
319 *pnPKey = nPK;
320 naz = nPK;
321 az = sqlite3_malloc( sizeof(char*)*(nPK+1) );
322 if( az==0 ) runtimeError("out of memory");
323 memset(az, 0, sizeof(char*)*(nPK+1));
drhd62c0f42015-04-09 13:34:29 +0000324 while( SQLITE_ROW==sqlite3_step(pStmt) ){
325 int iPKey;
326 if( truePk && (iPKey = sqlite3_column_int(pStmt,5))>0 ){
327 az[iPKey-1] = safeId((char*)sqlite3_column_text(pStmt,1));
328 }else{
329 az = sqlite3_realloc(az, sizeof(char*)*(naz+2) );
330 if( az==0 ) runtimeError("out of memory");
331 az[naz++] = safeId((char*)sqlite3_column_text(pStmt,1));
332 }
333 }
334 sqlite3_finalize(pStmt);
335 if( az ) az[naz] = 0;
336 if( az[0]==0 ){
337 const char *azRowid[] = { "rowid", "_rowid_", "oid" };
338 for(i=0; i<sizeof(azRowid)/sizeof(azRowid[0]); i++){
339 for(j=1; j<naz; j++){
340 if( sqlite3_stricmp(az[j], azRowid[i])==0 ) break;
341 }
342 if( j>=naz ){
343 az[0] = sqlite3_mprintf("%s", azRowid[i]);
344 break;
345 }
346 }
347 if( az[0]==0 ){
348 for(i=1; i<naz; i++) sqlite3_free(az[i]);
349 sqlite3_free(az);
350 az = 0;
351 }
352 }
353 return az;
354}
355
356/*
357** Print the sqlite3_value X as an SQL literal.
358*/
359static void printQuoted(sqlite3_value *X){
360 switch( sqlite3_value_type(X) ){
361 case SQLITE_FLOAT: {
362 double r1;
363 char zBuf[50];
364 r1 = sqlite3_value_double(X);
365 sqlite3_snprintf(sizeof(zBuf), zBuf, "%!.15g", r1);
366 printf("%s", zBuf);
367 break;
368 }
369 case SQLITE_INTEGER: {
370 printf("%lld", sqlite3_value_int64(X));
371 break;
372 }
373 case SQLITE_BLOB: {
374 const unsigned char *zBlob = sqlite3_value_blob(X);
375 int nBlob = sqlite3_value_bytes(X);
376 if( zBlob ){
377 int i;
378 printf("x'");
379 for(i=0; i<nBlob; i++){
380 printf("%02x", zBlob[i]);
381 }
382 printf("'");
383 }else{
384 printf("NULL");
385 }
386 break;
387 }
388 case SQLITE_TEXT: {
389 const unsigned char *zArg = sqlite3_value_text(X);
390 int i, j;
391
392 if( zArg==0 ){
393 printf("NULL");
394 }else{
395 printf("'");
396 for(i=j=0; zArg[i]; i++){
397 if( zArg[i]=='\'' ){
398 printf("%.*s'", i-j+1, &zArg[j]);
399 j = i+1;
400 }
401 }
402 printf("%s'", &zArg[j]);
403 }
404 break;
405 }
406 case SQLITE_NULL: {
407 printf("NULL");
408 break;
409 }
410 }
411}
412
413/*
414** Output SQL that will recreate the aux.zTab table.
415*/
416static void dump_table(const char *zTab){
417 char *zId = safeId(zTab); /* Name of the table */
418 char **az = 0; /* List of columns */
419 int nPk; /* Number of true primary key columns */
420 int nCol; /* Number of data columns */
421 int i; /* Loop counter */
422 sqlite3_stmt *pStmt; /* SQL statement */
423 const char *zSep; /* Separator string */
424 Str ins; /* Beginning of the INSERT statement */
425
426 pStmt = db_prepare("SELECT sql FROM aux.sqlite_master WHERE name=%Q", zTab);
427 if( SQLITE_ROW==sqlite3_step(pStmt) ){
428 printf("%s;\n", sqlite3_column_text(pStmt,0));
429 }
430 sqlite3_finalize(pStmt);
431 if( !g.bSchemaOnly ){
432 az = columnNames("aux", zTab, &nPk);
433 strInit(&ins);
434 if( az==0 ){
435 pStmt = db_prepare("SELECT * FROM aux.%s", zId);
436 strPrintf(&ins,"INSERT INTO %s VALUES", zId);
437 }else{
438 Str sql;
439 strInit(&sql);
440 zSep = "SELECT";
441 for(i=0; az[i]; i++){
442 strPrintf(&sql, "%s %s", zSep, az[i]);
443 zSep = ",";
444 }
445 strPrintf(&sql," FROM aux.%s", zId);
446 zSep = " ORDER BY";
447 for(i=1; i<=nPk; i++){
448 strPrintf(&sql, "%s %d", zSep, i);
449 zSep = ",";
450 }
451 pStmt = db_prepare("%s", sql.z);
452 strFree(&sql);
453 strPrintf(&ins, "INSERT INTO %s", zId);
454 zSep = "(";
455 for(i=0; az[i]; i++){
456 strPrintf(&ins, "%s%s", zSep, az[i]);
457 zSep = ",";
458 }
459 strPrintf(&ins,") VALUES");
460 namelistFree(az);
461 }
462 nCol = sqlite3_column_count(pStmt);
463 while( SQLITE_ROW==sqlite3_step(pStmt) ){
464 printf("%s",ins.z);
465 zSep = "(";
466 for(i=0; i<nCol; i++){
467 printf("%s",zSep);
468 printQuoted(sqlite3_column_value(pStmt,i));
469 zSep = ",";
470 }
471 printf(");\n");
472 }
473 sqlite3_finalize(pStmt);
474 strFree(&ins);
475 } /* endif !g.bSchemaOnly */
476 pStmt = db_prepare("SELECT sql FROM aux.sqlite_master"
477 " WHERE type='index' AND tbl_name=%Q AND sql IS NOT NULL",
478 zTab);
479 while( SQLITE_ROW==sqlite3_step(pStmt) ){
480 printf("%s;\n", sqlite3_column_text(pStmt,0));
481 }
482 sqlite3_finalize(pStmt);
483}
484
485
486/*
487** Compute all differences for a single table.
488*/
489static void diff_one_table(const char *zTab){
490 char *zId = safeId(zTab); /* Name of table (translated for us in SQL) */
491 char **az = 0; /* Columns in main */
492 char **az2 = 0; /* Columns in aux */
493 int nPk; /* Primary key columns in main */
494 int nPk2; /* Primary key columns in aux */
495 int n; /* Number of columns in main */
496 int n2; /* Number of columns in aux */
497 int nQ; /* Number of output columns in the diff query */
498 int i; /* Loop counter */
499 const char *zSep; /* Separator string */
500 Str sql; /* Comparison query */
501 sqlite3_stmt *pStmt; /* Query statement to do the diff */
502
503 strInit(&sql);
504 if( g.fDebug==DEBUG_COLUMN_NAMES ){
505 /* Simply run columnNames() on all tables of the origin
506 ** database and show the results. This is used for testing
507 ** and debugging of the columnNames() function.
508 */
509 az = columnNames("aux",zTab, &nPk);
510 if( az==0 ){
511 printf("Rowid not accessible for %s\n", zId);
512 }else{
513 printf("%s:", zId);
514 for(i=0; az[i]; i++){
515 printf(" %s", az[i]);
516 if( i+1==nPk ) printf(" *");
517 }
518 printf("\n");
519 }
520 goto end_diff_one_table;
521 }
522
523
524 if( sqlite3_table_column_metadata(g.db,"aux",zTab,0,0,0,0,0,0) ){
525 if( !sqlite3_table_column_metadata(g.db,"main",zTab,0,0,0,0,0,0) ){
526 /* Table missing from second database. */
527 printf("DROP TABLE %s;\n", zId);
528 }
529 goto end_diff_one_table;
530 }
531
532 if( sqlite3_table_column_metadata(g.db,"main",zTab,0,0,0,0,0,0) ){
533 /* Table missing from source */
534 dump_table(zTab);
535 goto end_diff_one_table;
536 }
537
538 az = columnNames("main", zTab, &nPk);
539 az2 = columnNames("aux", zTab, &nPk2);
540 if( az && az2 ){
541 for(n=0; az[n]; n++){
542 if( sqlite3_stricmp(az[n],az2[n])!=0 ) break;
543 }
544 }
545 if( az==0
546 || az2==0
547 || nPk!=nPk2
548 || az[n]
549 ){
550 /* Schema mismatch */
551 printf("DROP TABLE %s;\n", zId);
552 dump_table(zTab);
553 goto end_diff_one_table;
554 }
555
556 /* Build the comparison query */
557 for(n2=n; az[n2]; n2++){}
558 nQ = nPk2+1+2*(n2-nPk2);
559 if( n2>nPk2 ){
560 zSep = "SELECT ";
561 for(i=0; i<nPk; i++){
562 strPrintf(&sql, "%sB.%s", zSep, az[i]);
563 zSep = ", ";
564 }
565 strPrintf(&sql, ", 1%s -- changed row\n", nPk==n ? "" : ",");
566 while( az[i] ){
567 strPrintf(&sql, " A.%s IS NOT B.%s, B.%s%s\n",
568 az[i], az[i], az[i], i==n2-1 ? "" : ",");
569 i++;
570 }
571 strPrintf(&sql, " FROM main.%s A, aux.%s B\n", zId, zId);
572 zSep = " WHERE";
573 for(i=0; i<nPk; i++){
574 strPrintf(&sql, "%s A.%s=B.%s", zSep, az[i], az[i]);
575 zSep = " AND";
576 }
577 zSep = "\n AND (";
578 while( az[i] ){
579 strPrintf(&sql, "%sA.%s IS NOT B.%s%s\n",
580 zSep, az[i], az[i], i==n2-1 ? ")" : "");
581 zSep = " OR ";
582 i++;
583 }
584 strPrintf(&sql, " UNION ALL\n");
585 }
586 zSep = "SELECT ";
587 for(i=0; i<nPk; i++){
588 strPrintf(&sql, "%sA.%s", zSep, az[i]);
589 zSep = ", ";
590 }
591 strPrintf(&sql, ", 2%s -- deleted row\n", nPk==n ? "" : ",");
592 while( az[i] ){
593 strPrintf(&sql, " NULL, NULL%s\n", i==n2-1 ? "" : ",");
594 i++;
595 }
596 strPrintf(&sql, " FROM main.%s A\n", zId);
597 strPrintf(&sql, " WHERE NOT EXISTS(SELECT 1 FROM aux.%s B\n", zId);
598 zSep = " WHERE";
599 for(i=0; i<nPk; i++){
600 strPrintf(&sql, "%s A.%s=B.%s", zSep, az[i], az[i]);
601 zSep = " AND";
602 }
603 strPrintf(&sql, ")\n");
604 zSep = " UNION ALL\nSELECT ";
605 for(i=0; i<nPk; i++){
606 strPrintf(&sql, "%sB.%s", zSep, az[i]);
607 zSep = ", ";
608 }
609 strPrintf(&sql, ", 3%s -- inserted row\n", nPk==n ? "" : ",");
610 while( az2[i] ){
611 strPrintf(&sql, " 1, B.%s%s\n", az[i], i==n2-1 ? "" : ",");
612 i++;
613 }
614 strPrintf(&sql, " FROM aux.%s B\n", zId);
615 strPrintf(&sql, " WHERE NOT EXISTS(SELECT 1 FROM main.%s A\n", zId);
616 zSep = " WHERE";
617 for(i=0; i<nPk; i++){
618 strPrintf(&sql, "%s A.%s=B.%s", zSep, az[i], az[i]);
619 zSep = " AND";
620 }
621 strPrintf(&sql, ")\n ORDER BY");
622 zSep = " ";
623 for(i=1; i<=nPk; i++){
624 strPrintf(&sql, "%s%d", zSep, i);
625 zSep = ", ";
626 }
627 strPrintf(&sql, ";\n");
628
629 if( g.fDebug & DEBUG_DIFF_SQL ){
630 printf("SQL for %s:\n%s\n", zId, sql.z);
631 goto end_diff_one_table;
632 }
633
634 /* Drop indexes that are missing in the destination */
635 pStmt = db_prepare(
636 "SELECT name FROM main.sqlite_master"
637 " WHERE type='index' AND tbl_name=%Q"
638 " AND sql IS NOT NULL"
639 " AND sql NOT IN (SELECT sql FROM aux.sqlite_master"
640 " WHERE type='index' AND tbl_name=%Q"
641 " AND sql IS NOT NULL)",
642 zTab, zTab);
643 while( SQLITE_ROW==sqlite3_step(pStmt) ){
644 char *z = safeId((const char*)sqlite3_column_text(pStmt,0));
645 printf("DROP INDEX %s;\n", z);
646 sqlite3_free(z);
647 }
648 sqlite3_finalize(pStmt);
649
650 /* Run the query and output differences */
651 if( !g.bSchemaOnly ){
652 pStmt = db_prepare(sql.z);
653 while( SQLITE_ROW==sqlite3_step(pStmt) ){
654 int iType = sqlite3_column_int(pStmt, nPk);
655 if( iType==1 || iType==2 ){
656 if( iType==1 ){ /* Change the content of a row */
657 printf("UPDATE %s", zId);
658 zSep = " SET";
659 for(i=nPk+1; i<nQ; i+=2){
660 if( sqlite3_column_int(pStmt,i)==0 ) continue;
661 printf("%s %s=", zSep, az2[(i-1)/2]);
662 zSep = ",";
663 printQuoted(sqlite3_column_value(pStmt,i+1));
664 }
665 }else{ /* Delete a row */
666 printf("DELETE FROM %s", zId);
667 }
668 zSep = " WHERE";
669 for(i=0; i<nPk; i++){
670 printf("%s %s=", zSep, az2[i]);
671 printQuoted(sqlite3_column_value(pStmt,i));
672 zSep = ",";
673 }
674 printf(";\n");
675 }else{ /* Insert a row */
676 printf("INSERT INTO %s(%s", zId, az2[0]);
677 for(i=1; az2[i]; i++) printf(",%s", az2[i]);
678 printf(") VALUES");
679 zSep = "(";
680 for(i=0; i<nPk2; i++){
681 printf("%s", zSep);
682 zSep = ",";
683 printQuoted(sqlite3_column_value(pStmt,i));
684 }
685 for(i=nPk2+2; i<nQ; i+=2){
686 printf(",");
687 printQuoted(sqlite3_column_value(pStmt,i));
688 }
689 printf(");\n");
690 }
691 }
692 sqlite3_finalize(pStmt);
693 } /* endif !g.bSchemaOnly */
694
695 /* Create indexes that are missing in the source */
696 pStmt = db_prepare(
697 "SELECT sql FROM aux.sqlite_master"
698 " WHERE type='index' AND tbl_name=%Q"
699 " AND sql IS NOT NULL"
700 " AND sql NOT IN (SELECT sql FROM main.sqlite_master"
701 " WHERE type='index' AND tbl_name=%Q"
702 " AND sql IS NOT NULL)",
703 zTab, zTab);
704 while( SQLITE_ROW==sqlite3_step(pStmt) ){
705 printf("%s;\n", sqlite3_column_text(pStmt,0));
706 }
707 sqlite3_finalize(pStmt);
708
709end_diff_one_table:
710 strFree(&sql);
711 sqlite3_free(zId);
712 namelistFree(az);
713 namelistFree(az2);
714 return;
715}
716
717/*
718** Print sketchy documentation for this utility program
719*/
720static void showHelp(void){
721 printf("Usage: %s [options] DB1 DB2\n", g.zArgv0);
722 printf(
723"Output SQL text that would transform DB1 into DB2.\n"
724"Options:\n"
drha37591c2015-04-09 18:14:03 +0000725" --primarykey Use schema-defined PRIMARY KEYs\n"
drhd62c0f42015-04-09 13:34:29 +0000726" --schema Show only differences in the schema\n"
727" --table TAB Show only differences in table TAB\n"
728 );
729}
730
731int main(int argc, char **argv){
732 const char *zDb1 = 0;
733 const char *zDb2 = 0;
734 int i;
735 int rc;
736 char *zErrMsg = 0;
737 char *zSql;
738 sqlite3_stmt *pStmt;
739 char *zTab = 0;
740
741 g.zArgv0 = argv[0];
742 for(i=1; i<argc; i++){
743 const char *z = argv[i];
744 if( z[0]=='-' ){
745 z++;
746 if( z[0]=='-' ) z++;
747 if( strcmp(z,"debug")==0 ){
748 g.fDebug = strtol(argv[++i], 0, 0);
749 }else
750 if( strcmp(z,"help")==0 ){
751 showHelp();
752 return 0;
753 }else
drha37591c2015-04-09 18:14:03 +0000754 if( strcmp(z,"primarykey")==0 ){
755 g.bSchemaPK = 1;
756 }else
drhd62c0f42015-04-09 13:34:29 +0000757 if( strcmp(z,"schema")==0 ){
758 g.bSchemaOnly = 1;
759 }else
760 if( strcmp(z,"table")==0 ){
761 zTab = argv[++i];
762 }else
763 {
764 cmdlineError("unknown option: %s", argv[i]);
765 }
766 }else if( zDb1==0 ){
767 zDb1 = argv[i];
768 }else if( zDb2==0 ){
769 zDb2 = argv[i];
770 }else{
771 cmdlineError("unknown argument: %s", argv[i]);
772 }
773 }
774 if( zDb2==0 ){
775 cmdlineError("two database arguments required");
776 }
777 rc = sqlite3_open(zDb1, &g.db);
778 if( rc ){
779 cmdlineError("cannot open database file \"%s\"", zDb1);
780 }
781 rc = sqlite3_exec(g.db, "SELECT * FROM sqlite_master", 0, 0, &zErrMsg);
782 if( rc || zErrMsg ){
783 cmdlineError("\"%s\" does not appear to be a valid SQLite database", zDb1);
784 }
785 zSql = sqlite3_mprintf("ATTACH %Q as aux;", zDb2);
786 rc = sqlite3_exec(g.db, zSql, 0, 0, &zErrMsg);
787 if( rc || zErrMsg ){
788 cmdlineError("cannot attach database \"%s\"", zDb2);
789 }
790 rc = sqlite3_exec(g.db, "SELECT * FROM aux.sqlite_master", 0, 0, &zErrMsg);
791 if( rc || zErrMsg ){
792 cmdlineError("\"%s\" does not appear to be a valid SQLite database", zDb2);
793 }
794
795 if( zTab ){
796 diff_one_table(zTab);
797 }else{
798 /* Handle tables one by one */
799 pStmt = db_prepare(
800 "SELECT name FROM main.sqlite_master\n"
801 " WHERE type='table' AND sql NOT LIKE 'CREATE VIRTUAL%%'\n"
802 " UNION\n"
803 "SELECT name FROM aux.sqlite_master\n"
804 " WHERE type='table' AND sql NOT LIKE 'CREATE VIRTUAL%%'\n"
805 " ORDER BY name"
806 );
807 while( SQLITE_ROW==sqlite3_step(pStmt) ){
808 diff_one_table((const char*)sqlite3_column_text(pStmt, 0));
809 }
810 sqlite3_finalize(pStmt);
811 }
812
813 /* TBD: Handle trigger differences */
814 /* TBD: Handle view differences */
815 sqlite3_close(g.db);
816 return 0;
817}