blob: f5edd60143a675a640a676e790f65fdb7f32cd92 [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**
drh50be9c42015-04-17 12:16:09 +000013** This is a utility program that computes the differences in content
drhd62c0f42015-04-09 13:34:29 +000014** between two SQLite databases.
drh50be9c42015-04-17 12:16:09 +000015**
16** To compile, simply link against SQLite.
17**
18** See the showHelp() routine below for a brief description of how to
19** run the utility.
drhd62c0f42015-04-09 13:34:29 +000020*/
21#include <stdio.h>
22#include <stdlib.h>
23#include <stdarg.h>
24#include <ctype.h>
25#include <string.h>
26#include "sqlite3.h"
27
28/*
29** All global variables are gathered into the "g" singleton.
30*/
31struct GlobalVars {
32 const char *zArgv0; /* Name of program */
33 int bSchemaOnly; /* Only show schema differences */
drha37591c2015-04-09 18:14:03 +000034 int bSchemaPK; /* Use the schema-defined PK, not the true PK */
drhd62c0f42015-04-09 13:34:29 +000035 unsigned fDebug; /* Debug flags */
36 sqlite3 *db; /* The database connection */
37} g;
38
39/*
40** Allowed values for g.fDebug
41*/
42#define DEBUG_COLUMN_NAMES 0x000001
43#define DEBUG_DIFF_SQL 0x000002
44
45/*
46** Dynamic string object
47*/
48typedef struct Str Str;
49struct Str {
50 char *z; /* Text of the string */
51 int nAlloc; /* Bytes allocated in z[] */
52 int nUsed; /* Bytes actually used in z[] */
53};
54
55/*
56** Initialize a Str object
57*/
58static void strInit(Str *p){
59 p->z = 0;
60 p->nAlloc = 0;
61 p->nUsed = 0;
62}
63
64/*
65** Print an error resulting from faulting command-line arguments and
66** abort the program.
67*/
68static void cmdlineError(const char *zFormat, ...){
69 va_list ap;
70 fprintf(stderr, "%s: ", g.zArgv0);
71 va_start(ap, zFormat);
72 vfprintf(stderr, zFormat, ap);
73 va_end(ap);
74 fprintf(stderr, "\n\"%s --help\" for more help\n", g.zArgv0);
75 exit(1);
76}
77
78/*
79** Print an error message for an error that occurs at runtime, then
80** abort the program.
81*/
82static void runtimeError(const char *zFormat, ...){
83 va_list ap;
84 fprintf(stderr, "%s: ", g.zArgv0);
85 va_start(ap, zFormat);
86 vfprintf(stderr, zFormat, ap);
87 va_end(ap);
88 fprintf(stderr, "\n");
89 exit(1);
90}
91
92/*
93** Free all memory held by a Str object
94*/
95static void strFree(Str *p){
96 sqlite3_free(p->z);
97 strInit(p);
98}
99
100/*
101** Add formatted text to the end of a Str object
102*/
103static void strPrintf(Str *p, const char *zFormat, ...){
104 int nNew;
105 for(;;){
106 if( p->z ){
107 va_list ap;
108 va_start(ap, zFormat);
109 sqlite3_vsnprintf(p->nAlloc-p->nUsed, p->z+p->nUsed, zFormat, ap);
110 va_end(ap);
111 nNew = (int)strlen(p->z + p->nUsed);
112 }else{
113 nNew = p->nAlloc;
114 }
115 if( p->nUsed+nNew < p->nAlloc-1 ){
116 p->nUsed += nNew;
117 break;
118 }
119 p->nAlloc = p->nAlloc*2 + 1000;
120 p->z = sqlite3_realloc(p->z, p->nAlloc);
121 if( p->z==0 ) runtimeError("out of memory");
122 }
123}
124
125
126
127/* Safely quote an SQL identifier. Use the minimum amount of transformation
128** necessary to allow the string to be used with %s.
129**
130** Space to hold the returned string is obtained from sqlite3_malloc(). The
131** caller is responsible for ensuring this space is freed when no longer
132** needed.
133*/
134static char *safeId(const char *zId){
135 /* All SQLite keywords, in alphabetical order */
136 static const char *azKeywords[] = {
137 "ABORT", "ACTION", "ADD", "AFTER", "ALL", "ALTER", "ANALYZE", "AND", "AS",
138 "ASC", "ATTACH", "AUTOINCREMENT", "BEFORE", "BEGIN", "BETWEEN", "BY",
139 "CASCADE", "CASE", "CAST", "CHECK", "COLLATE", "COLUMN", "COMMIT",
140 "CONFLICT", "CONSTRAINT", "CREATE", "CROSS", "CURRENT_DATE",
141 "CURRENT_TIME", "CURRENT_TIMESTAMP", "DATABASE", "DEFAULT", "DEFERRABLE",
142 "DEFERRED", "DELETE", "DESC", "DETACH", "DISTINCT", "DROP", "EACH",
143 "ELSE", "END", "ESCAPE", "EXCEPT", "EXCLUSIVE", "EXISTS", "EXPLAIN",
144 "FAIL", "FOR", "FOREIGN", "FROM", "FULL", "GLOB", "GROUP", "HAVING", "IF",
145 "IGNORE", "IMMEDIATE", "IN", "INDEX", "INDEXED", "INITIALLY", "INNER",
146 "INSERT", "INSTEAD", "INTERSECT", "INTO", "IS", "ISNULL", "JOIN", "KEY",
147 "LEFT", "LIKE", "LIMIT", "MATCH", "NATURAL", "NO", "NOT", "NOTNULL",
148 "NULL", "OF", "OFFSET", "ON", "OR", "ORDER", "OUTER", "PLAN", "PRAGMA",
149 "PRIMARY", "QUERY", "RAISE", "RECURSIVE", "REFERENCES", "REGEXP",
150 "REINDEX", "RELEASE", "RENAME", "REPLACE", "RESTRICT", "RIGHT",
151 "ROLLBACK", "ROW", "SAVEPOINT", "SELECT", "SET", "TABLE", "TEMP",
152 "TEMPORARY", "THEN", "TO", "TRANSACTION", "TRIGGER", "UNION", "UNIQUE",
153 "UPDATE", "USING", "VACUUM", "VALUES", "VIEW", "VIRTUAL", "WHEN", "WHERE",
154 "WITH", "WITHOUT",
155 };
156 int lwr, upr, mid, c, i, x;
157 for(i=x=0; (c = zId[i])!=0; i++){
158 if( !isalpha(c) && c!='_' ){
159 if( i>0 && isdigit(c) ){
160 x++;
161 }else{
162 return sqlite3_mprintf("\"%w\"", zId);
163 }
164 }
165 }
166 if( x ) return sqlite3_mprintf("%s", zId);
167 lwr = 0;
168 upr = sizeof(azKeywords)/sizeof(azKeywords[0]) - 1;
169 while( lwr<=upr ){
170 mid = (lwr+upr)/2;
171 c = sqlite3_stricmp(azKeywords[mid], zId);
172 if( c==0 ) return sqlite3_mprintf("\"%w\"", zId);
173 if( c<0 ){
174 lwr = mid+1;
175 }else{
176 upr = mid-1;
177 }
178 }
179 return sqlite3_mprintf("%s", zId);
180}
181
182/*
183** Prepare a new SQL statement. Print an error and abort if anything
184** goes wrong.
185*/
186static sqlite3_stmt *db_vprepare(const char *zFormat, va_list ap){
187 char *zSql;
188 int rc;
189 sqlite3_stmt *pStmt;
190
191 zSql = sqlite3_vmprintf(zFormat, ap);
192 if( zSql==0 ) runtimeError("out of memory");
193 rc = sqlite3_prepare_v2(g.db, zSql, -1, &pStmt, 0);
194 if( rc ){
195 runtimeError("SQL statement error: %s\n\"%s\"", sqlite3_errmsg(g.db),
196 zSql);
197 }
198 sqlite3_free(zSql);
199 return pStmt;
200}
201static sqlite3_stmt *db_prepare(const char *zFormat, ...){
202 va_list ap;
203 sqlite3_stmt *pStmt;
204 va_start(ap, zFormat);
205 pStmt = db_vprepare(zFormat, ap);
206 va_end(ap);
207 return pStmt;
208}
209
210/*
211** Free a list of strings
212*/
213static void namelistFree(char **az){
214 if( az ){
215 int i;
216 for(i=0; az[i]; i++) sqlite3_free(az[i]);
217 sqlite3_free(az);
218 }
219}
220
221/*
222** Return a list of column names for the table zDb.zTab. Space to
drh39b355c2015-04-09 13:40:18 +0000223** hold the list is obtained from sqlite3_malloc() and should released
224** using namelistFree() when no longer needed.
drhd62c0f42015-04-09 13:34:29 +0000225**
drha37591c2015-04-09 18:14:03 +0000226** Primary key columns are listed first, followed by data columns.
227** The number of columns in the primary key is returned in *pnPkey.
drhd62c0f42015-04-09 13:34:29 +0000228**
drha37591c2015-04-09 18:14:03 +0000229** Normally, the "primary key" in the previous sentence is the true
230** primary key - the rowid or INTEGER PRIMARY KEY for ordinary tables
231** or the declared PRIMARY KEY for WITHOUT ROWID tables. However, if
232** the g.bSchemaPK flag is set, then the schema-defined PRIMARY KEY is
233** used in all cases. In that case, entries that have NULL values in
234** any of their primary key fields will be excluded from the analysis.
235**
236** If the primary key for a table is the rowid but rowid is inaccessible,
drhd62c0f42015-04-09 13:34:29 +0000237** then this routine returns a NULL pointer.
238**
239** Examples:
240** CREATE TABLE t1(a INT UNIQUE, b INTEGER, c TEXT, PRIMARY KEY(c));
241** *pnPKey = 1;
drha37591c2015-04-09 18:14:03 +0000242** az = { "rowid", "a", "b", "c", 0 } // Normal case
243** az = { "c", "a", "b", 0 } // g.bSchemaPK==1
drhd62c0f42015-04-09 13:34:29 +0000244**
245** CREATE TABLE t2(a INT UNIQUE, b INTEGER, c TEXT, PRIMARY KEY(b));
246** *pnPKey = 1;
247** az = { "b", "a", "c", 0 }
248**
249** CREATE TABLE t3(x,y,z,PRIMARY KEY(y,z));
drha37591c2015-04-09 18:14:03 +0000250** *pnPKey = 1 // Normal case
251** az = { "rowid", "x", "y", "z", 0 } // Normal case
252** *pnPKey = 2 // g.bSchemaPK==1
253** az = { "y", "x", "z", 0 } // g.bSchemaPK==1
drhd62c0f42015-04-09 13:34:29 +0000254**
255** CREATE TABLE t4(x,y,z,PRIMARY KEY(y,z)) WITHOUT ROWID;
256** *pnPKey = 2
257** az = { "y", "z", "x", 0 }
258**
259** CREATE TABLE t5(rowid,_rowid_,oid);
260** az = 0 // The rowid is not accessible
261*/
dan99461852015-07-30 20:26:16 +0000262static char **columnNames(
263 const char *zDb, /* Database ("main" or "aux") to query */
264 const char *zTab, /* Name of table to return details of */
265 int *pnPKey, /* OUT: Number of PK columns */
266 int *pbRowid /* OUT: True if PK is an implicit rowid */
267){
drha37591c2015-04-09 18:14:03 +0000268 char **az = 0; /* List of column names to be returned */
269 int naz = 0; /* Number of entries in az[] */
270 sqlite3_stmt *pStmt; /* SQL statement being run */
drhd62c0f42015-04-09 13:34:29 +0000271 char *zPkIdxName = 0; /* Name of the PRIMARY KEY index */
drha37591c2015-04-09 18:14:03 +0000272 int truePk = 0; /* PRAGMA table_info indentifies the PK to use */
drhd62c0f42015-04-09 13:34:29 +0000273 int nPK = 0; /* Number of PRIMARY KEY columns */
drha37591c2015-04-09 18:14:03 +0000274 int i, j; /* Loop counters */
drhd62c0f42015-04-09 13:34:29 +0000275
drha37591c2015-04-09 18:14:03 +0000276 if( g.bSchemaPK==0 ){
277 /* Normal case: Figure out what the true primary key is for the table.
278 ** * For WITHOUT ROWID tables, the true primary key is the same as
279 ** the schema PRIMARY KEY, which is guaranteed to be present.
280 ** * For rowid tables with an INTEGER PRIMARY KEY, the true primary
281 ** key is the INTEGER PRIMARY KEY.
282 ** * For all other rowid tables, the rowid is the true primary key.
283 */
284 pStmt = db_prepare("PRAGMA %s.index_list=%Q", zDb, zTab);
drhd62c0f42015-04-09 13:34:29 +0000285 while( SQLITE_ROW==sqlite3_step(pStmt) ){
drha37591c2015-04-09 18:14:03 +0000286 if( sqlite3_stricmp((const char*)sqlite3_column_text(pStmt,3),"pk")==0 ){
287 zPkIdxName = sqlite3_mprintf("%s", sqlite3_column_text(pStmt, 1));
288 break;
289 }
drhd62c0f42015-04-09 13:34:29 +0000290 }
291 sqlite3_finalize(pStmt);
drha37591c2015-04-09 18:14:03 +0000292 if( zPkIdxName ){
293 int nKey = 0;
294 int nCol = 0;
295 truePk = 0;
296 pStmt = db_prepare("PRAGMA %s.index_xinfo=%Q", zDb, zPkIdxName);
297 while( SQLITE_ROW==sqlite3_step(pStmt) ){
298 nCol++;
299 if( sqlite3_column_int(pStmt,5) ){ nKey++; continue; }
300 if( sqlite3_column_int(pStmt,1)>=0 ) truePk = 1;
301 }
302 if( nCol==nKey ) truePk = 1;
303 if( truePk ){
304 nPK = nKey;
305 }else{
306 nPK = 1;
307 }
308 sqlite3_finalize(pStmt);
309 sqlite3_free(zPkIdxName);
310 }else{
311 truePk = 1;
312 nPK = 1;
313 }
314 pStmt = db_prepare("PRAGMA %s.table_info=%Q", zDb, zTab);
drhd62c0f42015-04-09 13:34:29 +0000315 }else{
drha37591c2015-04-09 18:14:03 +0000316 /* The g.bSchemaPK==1 case: Use whatever primary key is declared
317 ** in the schema. The "rowid" will still be used as the primary key
318 ** if the table definition does not contain a PRIMARY KEY.
319 */
320 nPK = 0;
321 pStmt = db_prepare("PRAGMA %s.table_info=%Q", zDb, zTab);
322 while( SQLITE_ROW==sqlite3_step(pStmt) ){
323 if( sqlite3_column_int(pStmt,5)>0 ) nPK++;
324 }
325 sqlite3_reset(pStmt);
326 if( nPK==0 ) nPK = 1;
drhd62c0f42015-04-09 13:34:29 +0000327 truePk = 1;
drhd62c0f42015-04-09 13:34:29 +0000328 }
329 *pnPKey = nPK;
330 naz = nPK;
331 az = sqlite3_malloc( sizeof(char*)*(nPK+1) );
332 if( az==0 ) runtimeError("out of memory");
333 memset(az, 0, sizeof(char*)*(nPK+1));
drhd62c0f42015-04-09 13:34:29 +0000334 while( SQLITE_ROW==sqlite3_step(pStmt) ){
335 int iPKey;
336 if( truePk && (iPKey = sqlite3_column_int(pStmt,5))>0 ){
337 az[iPKey-1] = safeId((char*)sqlite3_column_text(pStmt,1));
338 }else{
339 az = sqlite3_realloc(az, sizeof(char*)*(naz+2) );
340 if( az==0 ) runtimeError("out of memory");
341 az[naz++] = safeId((char*)sqlite3_column_text(pStmt,1));
342 }
343 }
344 sqlite3_finalize(pStmt);
345 if( az ) az[naz] = 0;
dan99461852015-07-30 20:26:16 +0000346
347 /* If it is non-NULL, set *pbRowid to indicate whether or not the PK of
348 ** this table is an implicit rowid (*pbRowid==1) or not (*pbRowid==0). */
349 if( pbRowid ) *pbRowid = (az[0]==0);
350
351 /* If this table has an implicit rowid for a PK, figure out how to refer
352 ** to it. There are three options - "rowid", "_rowid_" and "oid". Any
353 ** of these will work, unless the table has an explicit column of the
354 ** same name. */
drhd62c0f42015-04-09 13:34:29 +0000355 if( az[0]==0 ){
356 const char *azRowid[] = { "rowid", "_rowid_", "oid" };
357 for(i=0; i<sizeof(azRowid)/sizeof(azRowid[0]); i++){
358 for(j=1; j<naz; j++){
359 if( sqlite3_stricmp(az[j], azRowid[i])==0 ) break;
360 }
361 if( j>=naz ){
362 az[0] = sqlite3_mprintf("%s", azRowid[i]);
363 break;
364 }
365 }
366 if( az[0]==0 ){
367 for(i=1; i<naz; i++) sqlite3_free(az[i]);
368 sqlite3_free(az);
369 az = 0;
370 }
371 }
372 return az;
373}
374
375/*
376** Print the sqlite3_value X as an SQL literal.
377*/
drh8a1cd762015-04-14 19:01:08 +0000378static void printQuoted(FILE *out, sqlite3_value *X){
drhd62c0f42015-04-09 13:34:29 +0000379 switch( sqlite3_value_type(X) ){
380 case SQLITE_FLOAT: {
381 double r1;
382 char zBuf[50];
383 r1 = sqlite3_value_double(X);
384 sqlite3_snprintf(sizeof(zBuf), zBuf, "%!.15g", r1);
drh8a1cd762015-04-14 19:01:08 +0000385 fprintf(out, "%s", zBuf);
drhd62c0f42015-04-09 13:34:29 +0000386 break;
387 }
388 case SQLITE_INTEGER: {
drh8a1cd762015-04-14 19:01:08 +0000389 fprintf(out, "%lld", sqlite3_value_int64(X));
drhd62c0f42015-04-09 13:34:29 +0000390 break;
391 }
392 case SQLITE_BLOB: {
393 const unsigned char *zBlob = sqlite3_value_blob(X);
394 int nBlob = sqlite3_value_bytes(X);
395 if( zBlob ){
396 int i;
drh8a1cd762015-04-14 19:01:08 +0000397 fprintf(out, "x'");
drhd62c0f42015-04-09 13:34:29 +0000398 for(i=0; i<nBlob; i++){
drh8a1cd762015-04-14 19:01:08 +0000399 fprintf(out, "%02x", zBlob[i]);
drhd62c0f42015-04-09 13:34:29 +0000400 }
drh8a1cd762015-04-14 19:01:08 +0000401 fprintf(out, "'");
drhd62c0f42015-04-09 13:34:29 +0000402 }else{
drh8a1cd762015-04-14 19:01:08 +0000403 fprintf(out, "NULL");
drhd62c0f42015-04-09 13:34:29 +0000404 }
405 break;
406 }
407 case SQLITE_TEXT: {
408 const unsigned char *zArg = sqlite3_value_text(X);
409 int i, j;
410
411 if( zArg==0 ){
drh8a1cd762015-04-14 19:01:08 +0000412 fprintf(out, "NULL");
drhd62c0f42015-04-09 13:34:29 +0000413 }else{
drh8a1cd762015-04-14 19:01:08 +0000414 fprintf(out, "'");
drhd62c0f42015-04-09 13:34:29 +0000415 for(i=j=0; zArg[i]; i++){
416 if( zArg[i]=='\'' ){
drh8a1cd762015-04-14 19:01:08 +0000417 fprintf(out, "%.*s'", i-j+1, &zArg[j]);
drhd62c0f42015-04-09 13:34:29 +0000418 j = i+1;
419 }
420 }
drh8a1cd762015-04-14 19:01:08 +0000421 fprintf(out, "%s'", &zArg[j]);
drhd62c0f42015-04-09 13:34:29 +0000422 }
423 break;
424 }
425 case SQLITE_NULL: {
drh8a1cd762015-04-14 19:01:08 +0000426 fprintf(out, "NULL");
drhd62c0f42015-04-09 13:34:29 +0000427 break;
428 }
429 }
430}
431
432/*
433** Output SQL that will recreate the aux.zTab table.
434*/
drh8a1cd762015-04-14 19:01:08 +0000435static void dump_table(const char *zTab, FILE *out){
drhd62c0f42015-04-09 13:34:29 +0000436 char *zId = safeId(zTab); /* Name of the table */
437 char **az = 0; /* List of columns */
438 int nPk; /* Number of true primary key columns */
439 int nCol; /* Number of data columns */
440 int i; /* Loop counter */
441 sqlite3_stmt *pStmt; /* SQL statement */
442 const char *zSep; /* Separator string */
443 Str ins; /* Beginning of the INSERT statement */
444
445 pStmt = db_prepare("SELECT sql FROM aux.sqlite_master WHERE name=%Q", zTab);
446 if( SQLITE_ROW==sqlite3_step(pStmt) ){
drh8a1cd762015-04-14 19:01:08 +0000447 fprintf(out, "%s;\n", sqlite3_column_text(pStmt,0));
drhd62c0f42015-04-09 13:34:29 +0000448 }
449 sqlite3_finalize(pStmt);
450 if( !g.bSchemaOnly ){
dan99461852015-07-30 20:26:16 +0000451 az = columnNames("aux", zTab, &nPk, 0);
drhd62c0f42015-04-09 13:34:29 +0000452 strInit(&ins);
453 if( az==0 ){
454 pStmt = db_prepare("SELECT * FROM aux.%s", zId);
455 strPrintf(&ins,"INSERT INTO %s VALUES", zId);
456 }else{
457 Str sql;
458 strInit(&sql);
459 zSep = "SELECT";
460 for(i=0; az[i]; i++){
461 strPrintf(&sql, "%s %s", zSep, az[i]);
462 zSep = ",";
463 }
464 strPrintf(&sql," FROM aux.%s", zId);
465 zSep = " ORDER BY";
466 for(i=1; i<=nPk; i++){
467 strPrintf(&sql, "%s %d", zSep, i);
468 zSep = ",";
469 }
470 pStmt = db_prepare("%s", sql.z);
471 strFree(&sql);
472 strPrintf(&ins, "INSERT INTO %s", zId);
473 zSep = "(";
474 for(i=0; az[i]; i++){
475 strPrintf(&ins, "%s%s", zSep, az[i]);
476 zSep = ",";
477 }
478 strPrintf(&ins,") VALUES");
479 namelistFree(az);
480 }
481 nCol = sqlite3_column_count(pStmt);
482 while( SQLITE_ROW==sqlite3_step(pStmt) ){
drh8a1cd762015-04-14 19:01:08 +0000483 fprintf(out, "%s",ins.z);
drhd62c0f42015-04-09 13:34:29 +0000484 zSep = "(";
485 for(i=0; i<nCol; i++){
drh8a1cd762015-04-14 19:01:08 +0000486 fprintf(out, "%s",zSep);
487 printQuoted(out, sqlite3_column_value(pStmt,i));
drhd62c0f42015-04-09 13:34:29 +0000488 zSep = ",";
489 }
drh8a1cd762015-04-14 19:01:08 +0000490 fprintf(out, ");\n");
drhd62c0f42015-04-09 13:34:29 +0000491 }
492 sqlite3_finalize(pStmt);
493 strFree(&ins);
494 } /* endif !g.bSchemaOnly */
495 pStmt = db_prepare("SELECT sql FROM aux.sqlite_master"
496 " WHERE type='index' AND tbl_name=%Q AND sql IS NOT NULL",
497 zTab);
498 while( SQLITE_ROW==sqlite3_step(pStmt) ){
drh8a1cd762015-04-14 19:01:08 +0000499 fprintf(out, "%s;\n", sqlite3_column_text(pStmt,0));
drhd62c0f42015-04-09 13:34:29 +0000500 }
501 sqlite3_finalize(pStmt);
502}
503
504
505/*
506** Compute all differences for a single table.
507*/
drh8a1cd762015-04-14 19:01:08 +0000508static void diff_one_table(const char *zTab, FILE *out){
drhd62c0f42015-04-09 13:34:29 +0000509 char *zId = safeId(zTab); /* Name of table (translated for us in SQL) */
510 char **az = 0; /* Columns in main */
511 char **az2 = 0; /* Columns in aux */
512 int nPk; /* Primary key columns in main */
513 int nPk2; /* Primary key columns in aux */
drhb3f3d642015-04-25 18:39:21 +0000514 int n = 0; /* Number of columns in main */
drhd62c0f42015-04-09 13:34:29 +0000515 int n2; /* Number of columns in aux */
516 int nQ; /* Number of output columns in the diff query */
517 int i; /* Loop counter */
518 const char *zSep; /* Separator string */
519 Str sql; /* Comparison query */
520 sqlite3_stmt *pStmt; /* Query statement to do the diff */
521
522 strInit(&sql);
523 if( g.fDebug==DEBUG_COLUMN_NAMES ){
524 /* Simply run columnNames() on all tables of the origin
525 ** database and show the results. This is used for testing
526 ** and debugging of the columnNames() function.
527 */
dan99461852015-07-30 20:26:16 +0000528 az = columnNames("aux",zTab, &nPk, 0);
drhd62c0f42015-04-09 13:34:29 +0000529 if( az==0 ){
530 printf("Rowid not accessible for %s\n", zId);
531 }else{
532 printf("%s:", zId);
533 for(i=0; az[i]; i++){
534 printf(" %s", az[i]);
535 if( i+1==nPk ) printf(" *");
536 }
537 printf("\n");
538 }
539 goto end_diff_one_table;
540 }
541
542
543 if( sqlite3_table_column_metadata(g.db,"aux",zTab,0,0,0,0,0,0) ){
544 if( !sqlite3_table_column_metadata(g.db,"main",zTab,0,0,0,0,0,0) ){
545 /* Table missing from second database. */
drh8a1cd762015-04-14 19:01:08 +0000546 fprintf(out, "DROP TABLE %s;\n", zId);
drhd62c0f42015-04-09 13:34:29 +0000547 }
548 goto end_diff_one_table;
549 }
550
551 if( sqlite3_table_column_metadata(g.db,"main",zTab,0,0,0,0,0,0) ){
552 /* Table missing from source */
drh8a1cd762015-04-14 19:01:08 +0000553 dump_table(zTab, out);
drhd62c0f42015-04-09 13:34:29 +0000554 goto end_diff_one_table;
555 }
556
dan99461852015-07-30 20:26:16 +0000557 az = columnNames("main", zTab, &nPk, 0);
558 az2 = columnNames("aux", zTab, &nPk2, 0);
drhd62c0f42015-04-09 13:34:29 +0000559 if( az && az2 ){
560 for(n=0; az[n]; n++){
561 if( sqlite3_stricmp(az[n],az2[n])!=0 ) break;
562 }
563 }
564 if( az==0
565 || az2==0
566 || nPk!=nPk2
567 || az[n]
568 ){
569 /* Schema mismatch */
drh8a1cd762015-04-14 19:01:08 +0000570 fprintf(out, "DROP TABLE %s;\n", zId);
571 dump_table(zTab, out);
drhd62c0f42015-04-09 13:34:29 +0000572 goto end_diff_one_table;
573 }
574
575 /* Build the comparison query */
576 for(n2=n; az[n2]; n2++){}
577 nQ = nPk2+1+2*(n2-nPk2);
578 if( n2>nPk2 ){
579 zSep = "SELECT ";
580 for(i=0; i<nPk; i++){
581 strPrintf(&sql, "%sB.%s", zSep, az[i]);
582 zSep = ", ";
583 }
584 strPrintf(&sql, ", 1%s -- changed row\n", nPk==n ? "" : ",");
585 while( az[i] ){
586 strPrintf(&sql, " A.%s IS NOT B.%s, B.%s%s\n",
587 az[i], az[i], az[i], i==n2-1 ? "" : ",");
588 i++;
589 }
590 strPrintf(&sql, " FROM main.%s A, aux.%s B\n", zId, zId);
591 zSep = " WHERE";
592 for(i=0; i<nPk; i++){
593 strPrintf(&sql, "%s A.%s=B.%s", zSep, az[i], az[i]);
594 zSep = " AND";
595 }
596 zSep = "\n AND (";
597 while( az[i] ){
598 strPrintf(&sql, "%sA.%s IS NOT B.%s%s\n",
599 zSep, az[i], az[i], i==n2-1 ? ")" : "");
600 zSep = " OR ";
601 i++;
602 }
603 strPrintf(&sql, " UNION ALL\n");
604 }
605 zSep = "SELECT ";
606 for(i=0; i<nPk; i++){
607 strPrintf(&sql, "%sA.%s", zSep, az[i]);
608 zSep = ", ";
609 }
610 strPrintf(&sql, ", 2%s -- deleted row\n", nPk==n ? "" : ",");
611 while( az[i] ){
612 strPrintf(&sql, " NULL, NULL%s\n", i==n2-1 ? "" : ",");
613 i++;
614 }
615 strPrintf(&sql, " FROM main.%s A\n", zId);
616 strPrintf(&sql, " WHERE NOT EXISTS(SELECT 1 FROM aux.%s B\n", zId);
617 zSep = " WHERE";
618 for(i=0; i<nPk; i++){
619 strPrintf(&sql, "%s A.%s=B.%s", zSep, az[i], az[i]);
620 zSep = " AND";
621 }
622 strPrintf(&sql, ")\n");
623 zSep = " UNION ALL\nSELECT ";
624 for(i=0; i<nPk; i++){
625 strPrintf(&sql, "%sB.%s", zSep, az[i]);
626 zSep = ", ";
627 }
628 strPrintf(&sql, ", 3%s -- inserted row\n", nPk==n ? "" : ",");
629 while( az2[i] ){
630 strPrintf(&sql, " 1, B.%s%s\n", az[i], i==n2-1 ? "" : ",");
631 i++;
632 }
633 strPrintf(&sql, " FROM aux.%s B\n", zId);
634 strPrintf(&sql, " WHERE NOT EXISTS(SELECT 1 FROM main.%s A\n", zId);
635 zSep = " WHERE";
636 for(i=0; i<nPk; i++){
637 strPrintf(&sql, "%s A.%s=B.%s", zSep, az[i], az[i]);
638 zSep = " AND";
639 }
640 strPrintf(&sql, ")\n ORDER BY");
641 zSep = " ";
642 for(i=1; i<=nPk; i++){
643 strPrintf(&sql, "%s%d", zSep, i);
644 zSep = ", ";
645 }
646 strPrintf(&sql, ";\n");
647
648 if( g.fDebug & DEBUG_DIFF_SQL ){
649 printf("SQL for %s:\n%s\n", zId, sql.z);
650 goto end_diff_one_table;
651 }
652
653 /* Drop indexes that are missing in the destination */
654 pStmt = db_prepare(
655 "SELECT name FROM main.sqlite_master"
656 " WHERE type='index' AND tbl_name=%Q"
657 " AND sql IS NOT NULL"
658 " AND sql NOT IN (SELECT sql FROM aux.sqlite_master"
659 " WHERE type='index' AND tbl_name=%Q"
660 " AND sql IS NOT NULL)",
661 zTab, zTab);
662 while( SQLITE_ROW==sqlite3_step(pStmt) ){
663 char *z = safeId((const char*)sqlite3_column_text(pStmt,0));
drh8a1cd762015-04-14 19:01:08 +0000664 fprintf(out, "DROP INDEX %s;\n", z);
drhd62c0f42015-04-09 13:34:29 +0000665 sqlite3_free(z);
666 }
667 sqlite3_finalize(pStmt);
668
669 /* Run the query and output differences */
670 if( !g.bSchemaOnly ){
671 pStmt = db_prepare(sql.z);
672 while( SQLITE_ROW==sqlite3_step(pStmt) ){
673 int iType = sqlite3_column_int(pStmt, nPk);
674 if( iType==1 || iType==2 ){
675 if( iType==1 ){ /* Change the content of a row */
drh8a1cd762015-04-14 19:01:08 +0000676 fprintf(out, "UPDATE %s", zId);
drhd62c0f42015-04-09 13:34:29 +0000677 zSep = " SET";
678 for(i=nPk+1; i<nQ; i+=2){
679 if( sqlite3_column_int(pStmt,i)==0 ) continue;
drh8a1cd762015-04-14 19:01:08 +0000680 fprintf(out, "%s %s=", zSep, az2[(i+nPk-1)/2]);
drhd62c0f42015-04-09 13:34:29 +0000681 zSep = ",";
drh8a1cd762015-04-14 19:01:08 +0000682 printQuoted(out, sqlite3_column_value(pStmt,i+1));
drhd62c0f42015-04-09 13:34:29 +0000683 }
684 }else{ /* Delete a row */
drh8a1cd762015-04-14 19:01:08 +0000685 fprintf(out, "DELETE FROM %s", zId);
drhd62c0f42015-04-09 13:34:29 +0000686 }
687 zSep = " WHERE";
688 for(i=0; i<nPk; i++){
drh8a1cd762015-04-14 19:01:08 +0000689 fprintf(out, "%s %s=", zSep, az2[i]);
690 printQuoted(out, sqlite3_column_value(pStmt,i));
drhd62c0f42015-04-09 13:34:29 +0000691 zSep = ",";
692 }
drh8a1cd762015-04-14 19:01:08 +0000693 fprintf(out, ";\n");
drhd62c0f42015-04-09 13:34:29 +0000694 }else{ /* Insert a row */
drh8a1cd762015-04-14 19:01:08 +0000695 fprintf(out, "INSERT INTO %s(%s", zId, az2[0]);
696 for(i=1; az2[i]; i++) fprintf(out, ",%s", az2[i]);
697 fprintf(out, ") VALUES");
drhd62c0f42015-04-09 13:34:29 +0000698 zSep = "(";
699 for(i=0; i<nPk2; i++){
drh8a1cd762015-04-14 19:01:08 +0000700 fprintf(out, "%s", zSep);
drhd62c0f42015-04-09 13:34:29 +0000701 zSep = ",";
drh8a1cd762015-04-14 19:01:08 +0000702 printQuoted(out, sqlite3_column_value(pStmt,i));
drhd62c0f42015-04-09 13:34:29 +0000703 }
704 for(i=nPk2+2; i<nQ; i+=2){
drh8a1cd762015-04-14 19:01:08 +0000705 fprintf(out, ",");
706 printQuoted(out, sqlite3_column_value(pStmt,i));
drhd62c0f42015-04-09 13:34:29 +0000707 }
drh8a1cd762015-04-14 19:01:08 +0000708 fprintf(out, ");\n");
drhd62c0f42015-04-09 13:34:29 +0000709 }
710 }
711 sqlite3_finalize(pStmt);
712 } /* endif !g.bSchemaOnly */
713
714 /* Create indexes that are missing in the source */
715 pStmt = db_prepare(
716 "SELECT sql FROM aux.sqlite_master"
717 " WHERE type='index' AND tbl_name=%Q"
718 " AND sql IS NOT NULL"
719 " AND sql NOT IN (SELECT sql FROM main.sqlite_master"
720 " WHERE type='index' AND tbl_name=%Q"
721 " AND sql IS NOT NULL)",
722 zTab, zTab);
723 while( SQLITE_ROW==sqlite3_step(pStmt) ){
drh8a1cd762015-04-14 19:01:08 +0000724 fprintf(out, "%s;\n", sqlite3_column_text(pStmt,0));
drhd62c0f42015-04-09 13:34:29 +0000725 }
726 sqlite3_finalize(pStmt);
727
728end_diff_one_table:
729 strFree(&sql);
730 sqlite3_free(zId);
731 namelistFree(az);
732 namelistFree(az2);
733 return;
734}
735
736/*
dan99461852015-07-30 20:26:16 +0000737** Check that table zTab exists and has the same schema in both the "main"
738** and "aux" databases currently opened by the global db handle. If they
739** do not, output an error message on stderr and exit(1). Otherwise, if
740** the schemas do match, return control to the caller.
741*/
742static void checkSchemasMatch(const char *zTab){
743 sqlite3_stmt *pStmt = db_prepare(
744 "SELECT A.sql=B.sql FROM main.sqlite_master A, aux.sqlite_master B"
745 " WHERE A.name=%Q AND B.name=%Q", zTab, zTab
746 );
747 if( SQLITE_ROW==sqlite3_step(pStmt) ){
748 if( sqlite3_column_int(pStmt,0)==0 ){
749 runtimeError("schema changes for table %s", safeId(zTab));
750 }
751 }else{
752 runtimeError("table %s missing from one or both databases", safeId(zTab));
753 }
754 sqlite3_finalize(pStmt);
755}
756
757static void strPrintfArray(
758 Str *pStr, /* String object to append to */
759 const char *zSep, /* Separator string */
760 const char *zFmt, /* Format for each entry */
761 char **az, int n /* Array of strings & its size (or -1) */
762){
763 int i;
764 for(i=0; az[i] && (i<n || n<0); i++){
765 if( i!=0 ) strPrintf(pStr, "%s", zSep);
766 strPrintf(pStr, zFmt, az[i], az[i], az[i]);
767 }
768}
769
770static void getRbudiffQuery(
771 const char *zTab,
772 char **azCol,
773 int nPK,
774 int bOtaRowid,
775 Str *pSql
776){
777 int i;
778
779 /* First the newly inserted rows: **/
780 strPrintf(pSql, "SELECT ");
781 strPrintfArray(pSql, ", ", "%s", azCol, -1);
782 strPrintf(pSql, ", 0"); /* Set ota_control to 0 for an insert */
783 strPrintf(pSql, " FROM aux.%Q AS n WHERE NOT EXISTS (\n", zTab);
784 strPrintf(pSql, " SELECT 1 FROM ", zTab);
785 strPrintf(pSql, " main.%Q AS o WHERE ", zTab);
786 strPrintfArray(pSql, " AND ", "(n.%Q IS o.%Q)", azCol, nPK);
787 strPrintf(pSql, "\n)");
788
789 /* Deleted rows: */
790 strPrintf(pSql, "\nUNION ALL\nSELECT ");
791 strPrintfArray(pSql, ", ", "%s", azCol, nPK);
dandd688e72015-07-31 15:13:29 +0000792 if( azCol[nPK] ){
793 strPrintf(pSql, ", ");
794 strPrintfArray(pSql, ", ", "NULL", &azCol[nPK], -1);
795 }
dan99461852015-07-30 20:26:16 +0000796 strPrintf(pSql, ", 1"); /* Set ota_control to 1 for a delete */
797 strPrintf(pSql, " FROM main.%Q AS n WHERE NOT EXISTS (\n", zTab);
798 strPrintf(pSql, " SELECT 1 FROM ", zTab);
799 strPrintf(pSql, " aux.%Q AS o WHERE ", zTab);
800 strPrintfArray(pSql, " AND ", "(n.%Q IS o.%Q)", azCol, nPK);
801 strPrintf(pSql, "\n) ");
802
dandd688e72015-07-31 15:13:29 +0000803 /* Updated rows. If all table columns are part of the primary key, there
804 ** can be no updates. In this case this part of the compound SELECT can
805 ** be omitted altogether. */
806 if( azCol[nPK] ){
807 strPrintf(pSql, "\nUNION ALL\nSELECT ");
808 strPrintfArray(pSql, ", ", "n.%s", azCol, nPK);
dan99461852015-07-30 20:26:16 +0000809 strPrintf(pSql, ",\n");
dandd688e72015-07-31 15:13:29 +0000810 strPrintfArray(pSql, " ,\n",
811 " CASE WHEN n.%s IS o.%s THEN NULL ELSE n.%s END", &azCol[nPK], -1
812 );
dan99461852015-07-30 20:26:16 +0000813
dandd688e72015-07-31 15:13:29 +0000814 if( bOtaRowid==0 ){
815 strPrintf(pSql, ", '");
816 strPrintfArray(pSql, "", ".", azCol, nPK);
817 strPrintf(pSql, "' ||\n");
818 }else{
819 strPrintf(pSql, ",\n");
820 }
821 strPrintfArray(pSql, " ||\n",
822 " CASE WHEN n.%s IS o.%s THEN '.' ELSE 'x' END", &azCol[nPK], -1
823 );
824 strPrintf(pSql, "\nAS ota_control");
825
826 strPrintf(pSql, "\nFROM main.%Q AS o, aux.%Q AS n\nWHERE ", zTab, zTab);
827 strPrintfArray(pSql, " AND ", "(n.%Q IS o.%Q)", azCol, nPK);
828 strPrintf(pSql, " AND ota_control LIKE '%%x%%'");
829 }
dan99461852015-07-30 20:26:16 +0000830
831 /* Now add an ORDER BY clause to sort everything by PK. */
832 strPrintf(pSql, "\nORDER BY ");
833 for(i=1; i<=nPK; i++) strPrintf(pSql, "%s%d", ((i>1)?", ":""), i);
834}
835
836static void rbudiff_one_table(const char *zTab, FILE *out){
837 int bOtaRowid; /* True to use an ota_rowid column */
838 int nPK; /* Number of primary key columns in table */
839 char **azCol; /* NULL terminated array of col names */
840 int i;
841 int nCol;
842 Str ct = {0, 0, 0}; /* The "CREATE TABLE data_xxx" statement */
843 Str sql = {0, 0, 0}; /* Query to find differences */
844 Str insert = {0, 0, 0}; /* First part of output INSERT statement */
845 sqlite3_stmt *pStmt = 0;
846
847 /* --rbu mode must use real primary keys. */
848 g.bSchemaPK = 1;
849
850 /* Check that the schemas of the two tables match. Exit early otherwise. */
851 checkSchemasMatch(zTab);
852
853 /* Grab the column names and PK details for the table(s). If no usable PK
854 ** columns are found, bail out early. */
855 azCol = columnNames("main", zTab, &nPK, &bOtaRowid);
856 if( azCol==0 ){
857 runtimeError("table %s has no usable PK columns", zTab);
858 }
859
860 /* Build and output the CREATE TABLE statement for the data_xxx table */
861 strPrintf(&ct, "CREATE TABLE IF NOT EXISTS 'data_%q'(", zTab);
862 if( bOtaRowid ) strPrintf(&ct, "rbu_rowid, ");
863 strPrintfArray(&ct, ", ", "%s", &azCol[bOtaRowid], -1);
864 strPrintf(&ct, ", rbu_control);");
865
866
867 /* Get the SQL for the query to retrieve data from the two databases */
868 getRbudiffQuery(zTab, azCol, nPK, bOtaRowid, &sql);
869
870 /* Build the first part of the INSERT statement output for each row
871 ** in the data_xxx table. */
872 strPrintf(&insert, "INSERT INTO 'data_%q' (", zTab);
873 if( bOtaRowid ) strPrintf(&insert, "rbu_rowid, ");
874 strPrintfArray(&insert, ", ", "%s", &azCol[bOtaRowid], -1);
875 strPrintf(&insert, ", rbu_control) VALUES(");
876
877 pStmt = db_prepare("%s", sql.z);
878 nCol = sqlite3_column_count(pStmt);
879 while( sqlite3_step(pStmt)==SQLITE_ROW ){
880 if( ct.z ){
881 fprintf(out, "%s\n", ct.z);
882 strFree(&ct);
883 }
884
885 fprintf(out, "%s", insert.z);
886 for(i=0; i<nCol; i++){
887 if( i>0 ) fprintf(out, ", ");
888 printQuoted(out, sqlite3_column_value(pStmt, i));
889 }
890 fprintf(out, ");\n");
891 }
892
893 sqlite3_finalize(pStmt);
894
895 strFree(&ct);
896 strFree(&sql);
897 strFree(&insert);
898}
899
900/*
drh8a1cd762015-04-14 19:01:08 +0000901** Display a summary of differences between two versions of the same
902** table table.
903**
904** * Number of rows changed
905** * Number of rows added
906** * Number of rows deleted
907** * Number of identical rows
908*/
909static void summarize_one_table(const char *zTab, FILE *out){
910 char *zId = safeId(zTab); /* Name of table (translated for us in SQL) */
911 char **az = 0; /* Columns in main */
912 char **az2 = 0; /* Columns in aux */
913 int nPk; /* Primary key columns in main */
914 int nPk2; /* Primary key columns in aux */
drhb3f3d642015-04-25 18:39:21 +0000915 int n = 0; /* Number of columns in main */
drh8a1cd762015-04-14 19:01:08 +0000916 int n2; /* Number of columns in aux */
917 int i; /* Loop counter */
918 const char *zSep; /* Separator string */
919 Str sql; /* Comparison query */
920 sqlite3_stmt *pStmt; /* Query statement to do the diff */
921 sqlite3_int64 nUpdate; /* Number of updated rows */
922 sqlite3_int64 nUnchanged; /* Number of unmodified rows */
923 sqlite3_int64 nDelete; /* Number of deleted rows */
924 sqlite3_int64 nInsert; /* Number of inserted rows */
925
926 strInit(&sql);
927 if( sqlite3_table_column_metadata(g.db,"aux",zTab,0,0,0,0,0,0) ){
928 if( !sqlite3_table_column_metadata(g.db,"main",zTab,0,0,0,0,0,0) ){
929 /* Table missing from second database. */
930 fprintf(out, "%s: missing from second database\n", zTab);
931 }
932 goto end_summarize_one_table;
933 }
934
935 if( sqlite3_table_column_metadata(g.db,"main",zTab,0,0,0,0,0,0) ){
936 /* Table missing from source */
937 fprintf(out, "%s: missing from first database\n", zTab);
938 goto end_summarize_one_table;
939 }
940
dan99461852015-07-30 20:26:16 +0000941 az = columnNames("main", zTab, &nPk, 0);
942 az2 = columnNames("aux", zTab, &nPk2, 0);
drh8a1cd762015-04-14 19:01:08 +0000943 if( az && az2 ){
944 for(n=0; az[n]; n++){
945 if( sqlite3_stricmp(az[n],az2[n])!=0 ) break;
946 }
947 }
948 if( az==0
949 || az2==0
950 || nPk!=nPk2
951 || az[n]
952 ){
953 /* Schema mismatch */
954 fprintf(out, "%s: incompatible schema\n", zTab);
955 goto end_summarize_one_table;
956 }
957
958 /* Build the comparison query */
959 for(n2=n; az[n2]; n2++){}
960 strPrintf(&sql, "SELECT 1, count(*)");
961 if( n2==nPk2 ){
962 strPrintf(&sql, ", 0\n");
963 }else{
964 zSep = ", sum(";
965 for(i=nPk; az[i]; i++){
966 strPrintf(&sql, "%sA.%s IS NOT B.%s", zSep, az[i], az[i]);
967 zSep = " OR ";
968 }
969 strPrintf(&sql, ")\n");
970 }
971 strPrintf(&sql, " FROM main.%s A, aux.%s B\n", zId, zId);
972 zSep = " WHERE";
973 for(i=0; i<nPk; i++){
974 strPrintf(&sql, "%s A.%s=B.%s", zSep, az[i], az[i]);
975 zSep = " AND";
976 }
977 strPrintf(&sql, " UNION ALL\n");
978 strPrintf(&sql, "SELECT 2, count(*), 0\n");
979 strPrintf(&sql, " FROM main.%s A\n", zId);
980 strPrintf(&sql, " WHERE NOT EXISTS(SELECT 1 FROM aux.%s B ", zId);
981 zSep = "WHERE";
982 for(i=0; i<nPk; i++){
983 strPrintf(&sql, "%s A.%s=B.%s", zSep, az[i], az[i]);
984 zSep = " AND";
985 }
986 strPrintf(&sql, ")\n");
987 strPrintf(&sql, " UNION ALL\n");
988 strPrintf(&sql, "SELECT 3, count(*), 0\n");
989 strPrintf(&sql, " FROM aux.%s B\n", zId);
990 strPrintf(&sql, " WHERE NOT EXISTS(SELECT 1 FROM main.%s A ", zId);
991 zSep = "WHERE";
992 for(i=0; i<nPk; i++){
993 strPrintf(&sql, "%s A.%s=B.%s", zSep, az[i], az[i]);
994 zSep = " AND";
995 }
996 strPrintf(&sql, ")\n ORDER BY 1;\n");
997
998 if( (g.fDebug & DEBUG_DIFF_SQL)!=0 ){
999 printf("SQL for %s:\n%s\n", zId, sql.z);
1000 goto end_summarize_one_table;
1001 }
1002
1003 /* Run the query and output difference summary */
1004 pStmt = db_prepare(sql.z);
1005 nUpdate = 0;
1006 nInsert = 0;
1007 nDelete = 0;
1008 nUnchanged = 0;
1009 while( SQLITE_ROW==sqlite3_step(pStmt) ){
1010 switch( sqlite3_column_int(pStmt,0) ){
1011 case 1:
1012 nUpdate = sqlite3_column_int64(pStmt,2);
1013 nUnchanged = sqlite3_column_int64(pStmt,1) - nUpdate;
1014 break;
1015 case 2:
1016 nDelete = sqlite3_column_int64(pStmt,1);
1017 break;
1018 case 3:
1019 nInsert = sqlite3_column_int64(pStmt,1);
1020 break;
1021 }
1022 }
1023 sqlite3_finalize(pStmt);
1024 fprintf(out, "%s: %lld changes, %lld inserts, %lld deletes, %lld unchanged\n",
1025 zTab, nUpdate, nInsert, nDelete, nUnchanged);
1026
1027end_summarize_one_table:
1028 strFree(&sql);
1029 sqlite3_free(zId);
1030 namelistFree(az);
1031 namelistFree(az2);
1032 return;
1033}
1034
1035/*
drh697e5db2015-04-11 12:07:40 +00001036** Write a 64-bit signed integer as a varint onto out
1037*/
1038static void putsVarint(FILE *out, sqlite3_uint64 v){
1039 int i, n;
drh6e42ce42015-04-11 13:48:01 +00001040 unsigned char p[12];
drh697e5db2015-04-11 12:07:40 +00001041 if( v & (((sqlite3_uint64)0xff000000)<<32) ){
1042 p[8] = (unsigned char)v;
1043 v >>= 8;
1044 for(i=7; i>=0; i--){
1045 p[i] = (unsigned char)((v & 0x7f) | 0x80);
1046 v >>= 7;
1047 }
1048 fwrite(p, 8, 1, out);
1049 }else{
1050 n = 9;
1051 do{
1052 p[n--] = (unsigned char)((v & 0x7f) | 0x80);
1053 v >>= 7;
1054 }while( v!=0 );
drh6e42ce42015-04-11 13:48:01 +00001055 p[9] &= 0x7f;
1056 fwrite(p+n+1, 9-n, 1, out);
1057 }
1058}
1059
1060/*
1061** Write an SQLite value onto out.
1062*/
1063static void putValue(FILE *out, sqlite3_value *pVal){
1064 int iDType = sqlite3_value_type(pVal);
1065 sqlite3_int64 iX;
1066 double rX;
1067 sqlite3_uint64 uX;
1068 int j;
1069
1070 putc(iDType, out);
1071 switch( iDType ){
1072 case SQLITE_INTEGER:
1073 iX = sqlite3_value_int64(pVal);
1074 memcpy(&uX, &iX, 8);
1075 for(j=56; j>=0; j-=8) putc((uX>>j)&0xff, out);
1076 break;
1077 case SQLITE_FLOAT:
drh33aa4db2015-05-04 15:04:47 +00001078 rX = sqlite3_value_double(pVal);
drh6e42ce42015-04-11 13:48:01 +00001079 memcpy(&uX, &rX, 8);
1080 for(j=56; j>=0; j-=8) putc((uX>>j)&0xff, out);
1081 break;
1082 case SQLITE_TEXT:
1083 iX = sqlite3_value_bytes(pVal);
1084 putsVarint(out, (sqlite3_uint64)iX);
drh33aa4db2015-05-04 15:04:47 +00001085 fwrite(sqlite3_value_text(pVal),1,(size_t)iX,out);
drh6e42ce42015-04-11 13:48:01 +00001086 break;
1087 case SQLITE_BLOB:
1088 iX = sqlite3_value_bytes(pVal);
1089 putsVarint(out, (sqlite3_uint64)iX);
drh33aa4db2015-05-04 15:04:47 +00001090 fwrite(sqlite3_value_blob(pVal),1,(size_t)iX,out);
drh6e42ce42015-04-11 13:48:01 +00001091 break;
1092 case SQLITE_NULL:
1093 break;
drh697e5db2015-04-11 12:07:40 +00001094 }
1095}
1096
1097/*
drh83e63dc2015-04-10 19:41:18 +00001098** Generate a CHANGESET for all differences from main.zTab to aux.zTab.
1099*/
1100static void changeset_one_table(const char *zTab, FILE *out){
1101 sqlite3_stmt *pStmt; /* SQL statment */
1102 char *zId = safeId(zTab); /* Escaped name of the table */
1103 char **azCol = 0; /* List of escaped column names */
1104 int nCol = 0; /* Number of columns */
1105 int *aiFlg = 0; /* 0 if column is not part of PK */
1106 int *aiPk = 0; /* Column numbers for each PK column */
1107 int nPk = 0; /* Number of PRIMARY KEY columns */
1108 Str sql; /* SQL for the diff query */
drh6e42ce42015-04-11 13:48:01 +00001109 int i, k; /* Loop counters */
drh83e63dc2015-04-10 19:41:18 +00001110 const char *zSep; /* List separator */
1111
dan99461852015-07-30 20:26:16 +00001112 /* Check that the schemas of the two tables match. Exit early otherwise. */
1113 checkSchemasMatch(zTab);
1114
drh83e63dc2015-04-10 19:41:18 +00001115 pStmt = db_prepare("PRAGMA main.table_info=%Q", zTab);
1116 while( SQLITE_ROW==sqlite3_step(pStmt) ){
1117 nCol++;
1118 azCol = sqlite3_realloc(azCol, sizeof(char*)*nCol);
1119 if( azCol==0 ) runtimeError("out of memory");
1120 aiFlg = sqlite3_realloc(aiFlg, sizeof(int)*nCol);
1121 if( aiFlg==0 ) runtimeError("out of memory");
1122 azCol[nCol-1] = safeId((const char*)sqlite3_column_text(pStmt,1));
1123 aiFlg[nCol-1] = i = sqlite3_column_int(pStmt,5);
1124 if( i>0 ){
1125 if( i>nPk ){
1126 nPk = i;
1127 aiPk = sqlite3_realloc(aiPk, sizeof(int)*nPk);
1128 if( aiPk==0 ) runtimeError("out of memory");
1129 }
1130 aiPk[i-1] = nCol-1;
1131 }
1132 }
1133 sqlite3_finalize(pStmt);
1134 if( nPk==0 ) goto end_changeset_one_table;
1135 strInit(&sql);
1136 if( nCol>nPk ){
drh697e5db2015-04-11 12:07:40 +00001137 strPrintf(&sql, "SELECT %d", SQLITE_UPDATE);
drh6e42ce42015-04-11 13:48:01 +00001138 for(i=0; i<nCol; i++){
1139 if( aiFlg[i] ){
1140 strPrintf(&sql, ",\n A.%s", azCol[i]);
1141 }else{
1142 strPrintf(&sql, ",\n A.%s IS NOT B.%s, A.%s, B.%s",
1143 azCol[i], azCol[i], azCol[i], azCol[i]);
1144 }
1145 }
drh83e63dc2015-04-10 19:41:18 +00001146 strPrintf(&sql,"\n FROM main.%s A, aux.%s B\n", zId, zId);
1147 zSep = " WHERE";
1148 for(i=0; i<nPk; i++){
1149 strPrintf(&sql, "%s A.%s=B.%s", zSep, azCol[aiPk[i]], azCol[aiPk[i]]);
1150 zSep = " AND";
1151 }
1152 zSep = "\n AND (";
1153 for(i=0; i<nCol; i++){
1154 if( aiFlg[i] ) continue;
1155 strPrintf(&sql, "%sA.%s IS NOT B.%s", zSep, azCol[i], azCol[i]);
1156 zSep = " OR\n ";
1157 }
1158 strPrintf(&sql,")\n UNION ALL\n");
1159 }
drh697e5db2015-04-11 12:07:40 +00001160 strPrintf(&sql, "SELECT %d", SQLITE_DELETE);
drh6e42ce42015-04-11 13:48:01 +00001161 for(i=0; i<nCol; i++){
1162 if( aiFlg[i] ){
1163 strPrintf(&sql, ",\n A.%s", azCol[i]);
1164 }else{
1165 strPrintf(&sql, ",\n 1, A.%s, NULL", azCol[i]);
1166 }
1167 }
1168 strPrintf(&sql, "\n FROM main.%s A\n", zId);
drh83e63dc2015-04-10 19:41:18 +00001169 strPrintf(&sql, " WHERE NOT EXISTS(SELECT 1 FROM aux.%s B\n", zId);
1170 zSep = " WHERE";
1171 for(i=0; i<nPk; i++){
1172 strPrintf(&sql, "%s A.%s=B.%s", zSep, azCol[aiPk[i]], azCol[aiPk[i]]);
1173 zSep = " AND";
1174 }
1175 strPrintf(&sql, ")\n UNION ALL\n");
drh697e5db2015-04-11 12:07:40 +00001176 strPrintf(&sql, "SELECT %d", SQLITE_INSERT);
drh6e42ce42015-04-11 13:48:01 +00001177 for(i=0; i<nCol; i++){
1178 if( aiFlg[i] ){
1179 strPrintf(&sql, ",\n B.%s", azCol[i]);
1180 }else{
1181 strPrintf(&sql, ",\n 1, NULL, B.%s", azCol[i]);
1182 }
1183 }
1184 strPrintf(&sql, "\n FROM aux.%s B\n", zId);
drh83e63dc2015-04-10 19:41:18 +00001185 strPrintf(&sql, " WHERE NOT EXISTS(SELECT 1 FROM main.%s A\n", zId);
1186 zSep = " WHERE";
1187 for(i=0; i<nPk; i++){
1188 strPrintf(&sql, "%s A.%s=B.%s", zSep, azCol[aiPk[i]], azCol[aiPk[i]]);
1189 zSep = " AND";
1190 }
1191 strPrintf(&sql, ")\n");
1192 strPrintf(&sql, " ORDER BY");
1193 zSep = " ";
1194 for(i=0; i<nPk; i++){
drh6e42ce42015-04-11 13:48:01 +00001195 strPrintf(&sql, "%s %d", zSep, aiPk[i]+2);
drh83e63dc2015-04-10 19:41:18 +00001196 zSep = ",";
1197 }
1198 strPrintf(&sql, ";\n");
1199
drh697e5db2015-04-11 12:07:40 +00001200 if( g.fDebug & DEBUG_DIFF_SQL ){
1201 printf("SQL for %s:\n%s\n", zId, sql.z);
1202 goto end_changeset_one_table;
1203 }
1204
1205 putc('T', out);
1206 putsVarint(out, (sqlite3_uint64)nCol);
1207 for(i=0; i<nCol; i++) putc(aiFlg[i]!=0, out);
1208 fwrite(zTab, 1, strlen(zTab), out);
1209 putc(0, out);
1210
1211 pStmt = db_prepare("%s", sql.z);
1212 while( SQLITE_ROW==sqlite3_step(pStmt) ){
1213 int iType = sqlite3_column_int(pStmt,0);
drh697e5db2015-04-11 12:07:40 +00001214 putc(iType, out);
1215 putc(0, out);
drh6e42ce42015-04-11 13:48:01 +00001216 switch( sqlite3_column_int(pStmt,0) ){
1217 case SQLITE_UPDATE: {
1218 for(k=1, i=0; i<nCol; i++){
1219 if( aiFlg[i] ){
1220 putValue(out, sqlite3_column_value(pStmt,k));
1221 k++;
1222 }else if( sqlite3_column_int(pStmt,k) ){
1223 putValue(out, sqlite3_column_value(pStmt,k+1));
1224 k += 3;
1225 }else{
1226 putc(0, out);
1227 k += 3;
1228 }
1229 }
1230 for(k=1, i=0; i<nCol; i++){
1231 if( aiFlg[i] ){
1232 putc(0, out);
1233 k++;
1234 }else if( sqlite3_column_int(pStmt,k) ){
1235 putValue(out, sqlite3_column_value(pStmt,k+2));
1236 k += 3;
1237 }else{
1238 putc(0, out);
1239 k += 3;
1240 }
1241 }
1242 break;
1243 }
1244 case SQLITE_INSERT: {
1245 for(k=1, i=0; i<nCol; i++){
1246 if( aiFlg[i] ){
1247 putValue(out, sqlite3_column_value(pStmt,k));
1248 k++;
1249 }else{
1250 putValue(out, sqlite3_column_value(pStmt,k+2));
1251 k += 3;
1252 }
1253 }
1254 break;
1255 }
1256 case SQLITE_DELETE: {
1257 for(k=1, i=0; i<nCol; i++){
1258 if( aiFlg[i] ){
1259 putValue(out, sqlite3_column_value(pStmt,k));
1260 k++;
1261 }else{
1262 putValue(out, sqlite3_column_value(pStmt,k+1));
1263 k += 3;
1264 }
1265 }
1266 break;
drh697e5db2015-04-11 12:07:40 +00001267 }
1268 }
1269 }
1270 sqlite3_finalize(pStmt);
drh83e63dc2015-04-10 19:41:18 +00001271
1272end_changeset_one_table:
1273 while( nCol>0 ) sqlite3_free(azCol[--nCol]);
1274 sqlite3_free(azCol);
1275 sqlite3_free(aiPk);
1276 sqlite3_free(zId);
1277}
1278
1279/*
drhd62c0f42015-04-09 13:34:29 +00001280** Print sketchy documentation for this utility program
1281*/
1282static void showHelp(void){
1283 printf("Usage: %s [options] DB1 DB2\n", g.zArgv0);
1284 printf(
1285"Output SQL text that would transform DB1 into DB2.\n"
1286"Options:\n"
drh83e63dc2015-04-10 19:41:18 +00001287" --changeset FILE Write a CHANGESET into FILE\n"
drh9a9219f2015-05-04 13:25:56 +00001288" -L|--lib LIBRARY Load an SQLite extension library\n"
drha37591c2015-04-09 18:14:03 +00001289" --primarykey Use schema-defined PRIMARY KEYs\n"
dan99461852015-07-30 20:26:16 +00001290" --rbu Output SQL to create/populate RBU table(s)\n"
drhd62c0f42015-04-09 13:34:29 +00001291" --schema Show only differences in the schema\n"
drh8a1cd762015-04-14 19:01:08 +00001292" --summary Show only a summary of the differences\n"
drhd62c0f42015-04-09 13:34:29 +00001293" --table TAB Show only differences in table TAB\n"
1294 );
1295}
1296
1297int main(int argc, char **argv){
1298 const char *zDb1 = 0;
1299 const char *zDb2 = 0;
1300 int i;
1301 int rc;
1302 char *zErrMsg = 0;
1303 char *zSql;
1304 sqlite3_stmt *pStmt;
1305 char *zTab = 0;
drh8a1cd762015-04-14 19:01:08 +00001306 FILE *out = stdout;
1307 void (*xDiff)(const char*,FILE*) = diff_one_table;
drh9a9219f2015-05-04 13:25:56 +00001308 int nExt = 0;
drh33aa4db2015-05-04 15:04:47 +00001309 char **azExt = 0;
drhd62c0f42015-04-09 13:34:29 +00001310
1311 g.zArgv0 = argv[0];
drhaa62e482015-05-12 00:46:40 +00001312 sqlite3_config(SQLITE_CONFIG_SINGLETHREAD);
drhd62c0f42015-04-09 13:34:29 +00001313 for(i=1; i<argc; i++){
1314 const char *z = argv[i];
1315 if( z[0]=='-' ){
1316 z++;
1317 if( z[0]=='-' ) z++;
drh83e63dc2015-04-10 19:41:18 +00001318 if( strcmp(z,"changeset")==0 ){
drh9a9219f2015-05-04 13:25:56 +00001319 if( i==argc-1 ) cmdlineError("missing argument to %s", argv[i]);
drh83e63dc2015-04-10 19:41:18 +00001320 out = fopen(argv[++i], "wb");
1321 if( out==0 ) cmdlineError("cannot open: %s", argv[i]);
drh8a1cd762015-04-14 19:01:08 +00001322 xDiff = changeset_one_table;
drh83e63dc2015-04-10 19:41:18 +00001323 }else
drhd62c0f42015-04-09 13:34:29 +00001324 if( strcmp(z,"debug")==0 ){
drh9a9219f2015-05-04 13:25:56 +00001325 if( i==argc-1 ) cmdlineError("missing argument to %s", argv[i]);
drhd62c0f42015-04-09 13:34:29 +00001326 g.fDebug = strtol(argv[++i], 0, 0);
1327 }else
1328 if( strcmp(z,"help")==0 ){
1329 showHelp();
1330 return 0;
1331 }else
drh6582ae52015-05-12 12:24:50 +00001332#ifndef SQLITE_OMIT_LOAD_EXTENSION
drh9a9219f2015-05-04 13:25:56 +00001333 if( strcmp(z,"lib")==0 || strcmp(z,"L")==0 ){
1334 if( i==argc-1 ) cmdlineError("missing argument to %s", argv[i]);
1335 azExt = realloc(azExt, sizeof(azExt[0])*(nExt+1));
1336 if( azExt==0 ) cmdlineError("out of memory");
1337 azExt[nExt++] = argv[++i];
1338 }else
drh6582ae52015-05-12 12:24:50 +00001339#endif
drha37591c2015-04-09 18:14:03 +00001340 if( strcmp(z,"primarykey")==0 ){
1341 g.bSchemaPK = 1;
1342 }else
dan99461852015-07-30 20:26:16 +00001343 if( strcmp(z,"rbu")==0 ){
1344 xDiff = rbudiff_one_table;
1345 }else
drhd62c0f42015-04-09 13:34:29 +00001346 if( strcmp(z,"schema")==0 ){
1347 g.bSchemaOnly = 1;
1348 }else
drh8a1cd762015-04-14 19:01:08 +00001349 if( strcmp(z,"summary")==0 ){
1350 xDiff = summarize_one_table;
1351 }else
drhd62c0f42015-04-09 13:34:29 +00001352 if( strcmp(z,"table")==0 ){
drh9a9219f2015-05-04 13:25:56 +00001353 if( i==argc-1 ) cmdlineError("missing argument to %s", argv[i]);
drhd62c0f42015-04-09 13:34:29 +00001354 zTab = argv[++i];
1355 }else
1356 {
1357 cmdlineError("unknown option: %s", argv[i]);
1358 }
1359 }else if( zDb1==0 ){
1360 zDb1 = argv[i];
1361 }else if( zDb2==0 ){
1362 zDb2 = argv[i];
1363 }else{
1364 cmdlineError("unknown argument: %s", argv[i]);
1365 }
1366 }
1367 if( zDb2==0 ){
1368 cmdlineError("two database arguments required");
1369 }
1370 rc = sqlite3_open(zDb1, &g.db);
1371 if( rc ){
1372 cmdlineError("cannot open database file \"%s\"", zDb1);
1373 }
1374 rc = sqlite3_exec(g.db, "SELECT * FROM sqlite_master", 0, 0, &zErrMsg);
1375 if( rc || zErrMsg ){
1376 cmdlineError("\"%s\" does not appear to be a valid SQLite database", zDb1);
1377 }
drh6582ae52015-05-12 12:24:50 +00001378#ifndef SQLITE_OMIT_LOAD_EXTENSION
drh9a9219f2015-05-04 13:25:56 +00001379 sqlite3_enable_load_extension(g.db, 1);
1380 for(i=0; i<nExt; i++){
1381 rc = sqlite3_load_extension(g.db, azExt[i], 0, &zErrMsg);
1382 if( rc || zErrMsg ){
1383 cmdlineError("error loading %s: %s", azExt[i], zErrMsg);
1384 }
1385 }
drh6582ae52015-05-12 12:24:50 +00001386#endif
drh9a9219f2015-05-04 13:25:56 +00001387 free(azExt);
drhd62c0f42015-04-09 13:34:29 +00001388 zSql = sqlite3_mprintf("ATTACH %Q as aux;", zDb2);
1389 rc = sqlite3_exec(g.db, zSql, 0, 0, &zErrMsg);
1390 if( rc || zErrMsg ){
1391 cmdlineError("cannot attach database \"%s\"", zDb2);
1392 }
1393 rc = sqlite3_exec(g.db, "SELECT * FROM aux.sqlite_master", 0, 0, &zErrMsg);
1394 if( rc || zErrMsg ){
1395 cmdlineError("\"%s\" does not appear to be a valid SQLite database", zDb2);
1396 }
1397
1398 if( zTab ){
drh8a1cd762015-04-14 19:01:08 +00001399 xDiff(zTab, out);
drhd62c0f42015-04-09 13:34:29 +00001400 }else{
1401 /* Handle tables one by one */
1402 pStmt = db_prepare(
1403 "SELECT name FROM main.sqlite_master\n"
1404 " WHERE type='table' AND sql NOT LIKE 'CREATE VIRTUAL%%'\n"
1405 " UNION\n"
1406 "SELECT name FROM aux.sqlite_master\n"
1407 " WHERE type='table' AND sql NOT LIKE 'CREATE VIRTUAL%%'\n"
1408 " ORDER BY name"
1409 );
1410 while( SQLITE_ROW==sqlite3_step(pStmt) ){
drh8a1cd762015-04-14 19:01:08 +00001411 xDiff((const char*)sqlite3_column_text(pStmt,0), out);
drhd62c0f42015-04-09 13:34:29 +00001412 }
1413 sqlite3_finalize(pStmt);
1414 }
1415
1416 /* TBD: Handle trigger differences */
1417 /* TBD: Handle view differences */
1418 sqlite3_close(g.db);
1419 return 0;
1420}