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