Many hyperlinks are disabled.
Use anonymous login
to enable hyperlinks.
Overview
Comment: | First attempt at a utility program to compute sqlite_stat1 without doing a full table scan. |
---|---|
Downloads: | Tarball | ZIP archive |
Timelines: | family | ancestors | descendants | both | est_count_pragma |
Files: | files | file ages | folders |
SHA1: |
7b83581a43384fe81dc319482e03be0d |
User & Date: | drh 2016-10-25 13:57:40.551 |
Context
2016-10-25
| ||
17:28 | Merge recent trunk changes, and especially the PRAGMA index_info enhancement which is needed on this branch. (check-in: c3570e462a user: drh tags: est_count_pragma) | |
13:57 | First attempt at a utility program to compute sqlite_stat1 without doing a full table scan. (check-in: 7b83581a43 user: drh tags: est_count_pragma) | |
2016-10-21
| ||
18:01 | When reading from an index, the shared-cache lock must be on the corresponding table. (check-in: 04fe12b590 user: drh tags: est_count_pragma) | |
Changes
Changes to main.mk.
︙ | ︙ | |||
492 493 494 495 496 497 498 499 500 501 502 503 504 505 | sqldiff$(EXE): $(TOP)/tool/sqldiff.c sqlite3.c sqlite3.h $(TCCX) -o sqldiff$(EXE) -DSQLITE_THREADSAFE=0 \ $(TOP)/tool/sqldiff.c sqlite3.c $(TLIBS) $(THREADLIB) dbhash$(EXE): $(TOP)/tool/dbhash.c sqlite3.c sqlite3.h $(TCCX) -o dbhash$(EXE) -DSQLITE_THREADSAFE=0 \ $(TOP)/tool/dbhash.c sqlite3.c $(TLIBS) $(THREADLIB) scrub$(EXE): $(TOP)/ext/misc/scrub.c sqlite3.o $(TCC) -I. -DSCRUB_STANDALONE -o scrub$(EXE) $(TOP)/ext/misc/scrub.c sqlite3.o $(THREADLIB) srcck1$(EXE): $(TOP)/tool/srcck1.c $(BCC) -o srcck1$(EXE) $(TOP)/tool/srcck1.c | > > > > | 492 493 494 495 496 497 498 499 500 501 502 503 504 505 506 507 508 509 | sqldiff$(EXE): $(TOP)/tool/sqldiff.c sqlite3.c sqlite3.h $(TCCX) -o sqldiff$(EXE) -DSQLITE_THREADSAFE=0 \ $(TOP)/tool/sqldiff.c sqlite3.c $(TLIBS) $(THREADLIB) dbhash$(EXE): $(TOP)/tool/dbhash.c sqlite3.c sqlite3.h $(TCCX) -o dbhash$(EXE) -DSQLITE_THREADSAFE=0 \ $(TOP)/tool/dbhash.c sqlite3.c $(TLIBS) $(THREADLIB) faststat1$(EXE): $(TOP)/tool/faststat1.c sqlite3.c sqlite3.h $(TCCX) -o faststat1$(EXE) -DSQLITE_THREADSAFE=0 \ $(TOP)/tool/faststat1.c sqlite3.c $(TLIBS) $(THREADLIB) scrub$(EXE): $(TOP)/ext/misc/scrub.c sqlite3.o $(TCC) -I. -DSCRUB_STANDALONE -o scrub$(EXE) $(TOP)/ext/misc/scrub.c sqlite3.o $(THREADLIB) srcck1$(EXE): $(TOP)/tool/srcck1.c $(BCC) -o srcck1$(EXE) $(TOP)/tool/srcck1.c |
︙ | ︙ |
Added tool/faststat1.c.
> > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > | 1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 22 23 24 25 26 27 28 29 30 31 32 33 34 35 36 37 38 39 40 41 42 43 44 45 46 47 48 49 50 51 52 53 54 55 56 57 58 59 60 61 62 63 64 65 66 67 68 69 70 71 72 73 74 75 76 77 78 79 80 81 82 83 84 85 86 87 88 89 90 91 92 93 94 95 96 97 98 99 100 101 102 103 104 105 106 107 108 109 110 111 112 113 114 115 116 117 118 119 120 121 122 123 124 125 126 127 128 129 130 131 132 133 134 135 136 137 138 139 140 141 142 143 144 145 146 147 148 149 150 151 152 153 154 155 156 157 158 159 160 161 162 163 164 165 166 167 168 169 170 171 172 173 174 175 176 177 178 179 180 181 182 183 184 185 186 187 188 189 190 191 192 193 194 195 196 197 198 199 200 201 202 203 204 205 206 207 208 209 210 211 212 213 214 215 216 217 218 219 220 221 222 223 224 225 226 227 228 229 230 231 232 233 234 235 236 237 238 239 240 241 242 243 244 245 246 247 248 249 250 251 252 253 254 255 256 257 258 259 260 261 262 263 264 265 266 267 268 269 270 271 272 273 274 275 276 277 278 279 280 281 282 283 284 285 286 287 288 289 290 291 292 293 294 295 296 297 298 299 300 301 302 303 304 305 306 307 308 309 310 311 312 313 314 315 316 317 318 319 320 321 322 323 324 325 326 327 328 329 330 331 332 333 334 335 336 337 338 339 340 341 342 343 344 345 346 347 348 349 350 351 352 353 354 355 356 357 358 359 360 361 362 363 364 365 366 367 368 369 370 371 372 373 374 375 376 377 378 379 380 381 382 383 384 385 386 387 388 389 390 391 392 393 394 395 396 397 398 399 400 401 402 403 404 405 406 407 408 409 410 411 412 413 414 415 416 417 418 419 420 421 422 423 | /* ** 2016-10-24 ** ** The author disclaims copyright to this source code. In place of ** a legal notice, here is a blessing: ** ** May you do good and not evil. ** May you find forgiveness for yourself and forgive others. ** May you share freely, never taking more than you give. ** ************************************************************************* ** ** This is a utility program that uses the est_count and btree_sample ** pragmas to try to approximate the content of the sqlite_stat1 table ** without doing a full table scan. ** ** To compile, simply link against SQLite. ** ** See the showHelp() routine below for a brief description of how to ** run the utility. */ #include <stdio.h> #include <stdlib.h> #include <stdarg.h> #include <ctype.h> #include <string.h> #include <assert.h> #include "sqlite3.h" /* ** All global variables are gathered into the "g" singleton. */ struct GlobalVars { const char *zArgv0; /* Name of program */ unsigned fDebug; /* Debug flags */ sqlite3 *db; /* The database connection */ } g; /* ** Allowed values for g.fDebug */ #define DEBUG_NONE 0 /* ** Print an error resulting from faulting command-line arguments and ** abort the program. */ static void cmdlineError(const char *zFormat, ...){ va_list ap; fprintf(stderr, "%s: ", g.zArgv0); va_start(ap, zFormat); vfprintf(stderr, zFormat, ap); va_end(ap); fprintf(stderr, "\n\"%s --help\" for more help\n", g.zArgv0); exit(1); } /* ** Print an error message for an error that occurs at runtime, then ** abort the program. */ static void runtimeError(const char *zFormat, ...){ va_list ap; fprintf(stderr, "%s: ", g.zArgv0); va_start(ap, zFormat); vfprintf(stderr, zFormat, ap); va_end(ap); fprintf(stderr, "\n"); exit(1); } /* ** Prepare a new SQL statement. Print an error and abort if anything ** goes wrong. */ static sqlite3_stmt *db_vprepare(const char *zFormat, va_list ap){ char *zSql; int rc; sqlite3_stmt *pStmt; zSql = sqlite3_vmprintf(zFormat, ap); if( zSql==0 ) runtimeError("out of memory"); rc = sqlite3_prepare_v2(g.db, zSql, -1, &pStmt, 0); if( rc ){ runtimeError("SQL statement error: %s\n\"%s\"", sqlite3_errmsg(g.db), zSql); } sqlite3_free(zSql); return pStmt; } static sqlite3_stmt *db_prepare(const char *zFormat, ...){ va_list ap; sqlite3_stmt *pStmt; va_start(ap, zFormat); pStmt = db_vprepare(zFormat, ap); va_end(ap); return pStmt; } /* ** Estimate the number of rows in the given table or index. */ static sqlite3_int64 estEntryCount(const char *zTabIdx){ double sum = 0.0; int i; int n = 0; sqlite3_stmt *pStmt; # define N_CNT_SAMPLE 10 for(i=0; i<=N_CNT_SAMPLE; i++){ pStmt = db_prepare("PRAGMA est_count(\"%w\",%g)", zTabIdx, ((double)i)/(double)(N_CNT_SAMPLE)); if( sqlite3_step(pStmt)==SQLITE_ROW ){ sum += sqlite3_column_double(pStmt, 0); n++; } sqlite3_finalize(pStmt); } return n==0 ? 0 : (sqlite3_int64)(sum/n); } /* ** Stat1 for a table. */ static void analyzeTable(const char *zTab){ sqlite3_int64 n = estEntryCount(zTab); sqlite3_stmt *pStmt; if( n==0 ){ printf("-- empty table: %s\n", zTab); return; } pStmt = db_prepare( "INSERT INTO temp.est_stat1(tbl,idx,stat)" "VALUES(\"%w\",NULL,'%lld')", zTab, n ); sqlite3_step(pStmt); sqlite3_finalize(pStmt); } /* ** Compare the i-th column of pStmt against pValue. Return true if they ** are different. */ static int columnNotEqual(sqlite3_stmt *pStmt, int i, sqlite3_value *pValue){ int n1, n2, n; if( sqlite3_column_type(pStmt,i)!=sqlite3_value_type(pValue) ) return 1; switch( sqlite3_column_type(pStmt,i) ){ case SQLITE_NULL: return 0; /* Nulls compare equal to one another in this context */ case SQLITE_INTEGER: return sqlite3_column_int64(pStmt,i)!=sqlite3_value_int64(pValue); case SQLITE_FLOAT: return sqlite3_column_double(pStmt,i)!=sqlite3_value_double(pValue); case SQLITE_BLOB: n1 = sqlite3_column_bytes(pStmt,i); n2 = sqlite3_value_bytes(pValue); n = n1<n2 ? n1 : n2; if( memcmp(sqlite3_column_blob(pStmt,i), sqlite3_value_blob(pValue),n) ){ return 1; } return n1!=n2; case SQLITE_TEXT: n1 = sqlite3_column_bytes(pStmt,i); n2 = sqlite3_value_bytes(pValue); n = n1<n2 ? n1 : n2; if( memcmp(sqlite3_column_text(pStmt,i), sqlite3_value_text(pValue),n) ){ return 1; } return n1!=n2; } return 1; } /* ** Stat1 for an index; */ static void analyzeIndex(const char *zTab, const char *zIdx){ sqlite3_int64 n = estEntryCount(zIdx); sqlite3_stmt *pStmt; sqlite3_uint64 *aCnt; sqlite3_value **apValue; int nCol = 0; int nByte; int i, j, k; int iLimit; int nRow = 0; char *zRes; int szRes; int rc; # define N_SPAN 5 if( n==0 ) return; pStmt = db_prepare("PRAGMA index_xinfo=\"%w\"", zIdx); while( sqlite3_step(pStmt)==SQLITE_ROW ){ const char *zColl = (const char*)sqlite3_column_text(pStmt,4); if( sqlite3_stricmp(zColl,"binary")!=0 ){ printf("-- cannot analyze index \"%s\" because column \"%s\" uses" " collating sequence \"%s\".\n", zIdx, sqlite3_column_text(pStmt, 2), zColl); sqlite3_finalize(pStmt); return; } if( sqlite3_column_int(pStmt, 5)==0 ) break; nCol++; } sqlite3_finalize(pStmt); nByte = (sizeof(aCnt[0]) + sizeof(apValue[0]))*nCol + 30*(nCol+1); aCnt = sqlite3_malloc( nByte ); if( aCnt==0 ){ runtimeError("out of memory"); } memset(aCnt, 0, nByte); apValue = (sqlite3_value**)&aCnt[nCol]; zRes = (char*)&apValue[nCol]; szRes = 30*(nCol+1); iLimit = n>10000 ? 100 : 20000; pStmt = db_prepare("PRAGMA btree_sample(\"%w\",0.0,%lld)", zIdx, n*2); for(i=0; i<N_SPAN; i++){ k = 0; while( k<iLimit && (rc = sqlite3_step(pStmt))==SQLITE_ROW ){ int iFirst; for(iFirst=0; iFirst<nCol; iFirst++){ if( apValue[iFirst]==0 ) break; if( columnNotEqual(pStmt, iFirst, apValue[iFirst]) ) break; } for(j=iFirst; j<nCol; j++){ aCnt[j]++; sqlite3_value_free(apValue[j]); apValue[j] = sqlite3_value_dup(sqlite3_column_value(pStmt,j)); } nRow++; k++; } sqlite3_finalize(pStmt); if( rc!=SQLITE_ROW || i==N_SPAN-1 ) break; pStmt = db_prepare("PRAGMA btree_sample(\"%w\",%g,%lld)", zIdx, ((double)i)/(double)N_SPAN, n*2); } for(j=0; j<nCol; j++) sqlite3_value_free(apValue[j]); sqlite3_snprintf(szRes, zRes, "%lld", n); k = (int)strlen(zRes); for(j=0; j<nCol; j++){ sqlite3_snprintf(szRes-k, zRes+k, " %d", nRow/aCnt[j]); k += (int)strlen(zRes+k); } pStmt = db_prepare( "INSERT INTO temp.est_stat1(tbl,idx,stat)" "VALUES(\"%w\",\"%w\",'%s')", zTab, zIdx, zRes ); sqlite3_step(pStmt); sqlite3_finalize(pStmt); } /* ** Print the sqlite3_value X as an SQL literal. */ static void printQuoted(FILE *out, sqlite3_value *X){ switch( sqlite3_value_type(X) ){ case SQLITE_FLOAT: { double r1; char zBuf[50]; r1 = sqlite3_value_double(X); sqlite3_snprintf(sizeof(zBuf), zBuf, "%!.15g", r1); fprintf(out, "%s", zBuf); break; } case SQLITE_INTEGER: { fprintf(out, "%lld", sqlite3_value_int64(X)); break; } case SQLITE_BLOB: { const unsigned char *zBlob = sqlite3_value_blob(X); int nBlob = sqlite3_value_bytes(X); if( zBlob ){ int i; fprintf(out, "x'"); for(i=0; i<nBlob; i++){ fprintf(out, "%02x", zBlob[i]); } fprintf(out, "'"); }else{ /* Could be an OOM, could be a zero-byte blob */ fprintf(out, "X''"); } break; } case SQLITE_TEXT: { const unsigned char *zArg = sqlite3_value_text(X); int i, j; if( zArg==0 ){ fprintf(out, "NULL"); }else{ fprintf(out, "'"); for(i=j=0; zArg[i]; i++){ if( zArg[i]=='\'' ){ fprintf(out, "%.*s'", i-j+1, &zArg[j]); j = i+1; } } fprintf(out, "%s'", &zArg[j]); } break; } case SQLITE_NULL: { fprintf(out, "NULL"); break; } } } /* ** Output SQL that will recreate the aux.zTab table. */ static void dump_table(const char *zTab, const char *zAlias){ int i; /* Loop counter */ int nCol; /* Number of result columns */ sqlite3_stmt *pStmt; /* SQL statement */ const char *zSep; /* Separator string */ pStmt = db_prepare("SELECT * FROM %s", zTab); nCol = sqlite3_column_count(pStmt); while( SQLITE_ROW==sqlite3_step(pStmt) ){ printf("INSERT INTO %s VALUES", zAlias); zSep = "("; for(i=0; i<nCol; i++){ fprintf(stdout, "%s",zSep); printQuoted(stdout, sqlite3_column_value(pStmt,i)); zSep = ","; } fprintf(stdout, ");\n"); } sqlite3_finalize(pStmt); } /* ** Print sketchy documentation for this utility program */ static void showHelp(void){ printf("Usage: %s [options] DBFILE\n", g.zArgv0); printf( "Generate an approximate sqlite_stat1 table for the database in the DBFILE\n" "file. Write the result to standard output.\n" "Options:\n" " (none yet....)\n" ); } int main(int argc, char **argv){ const char *zDb = 0; int i; int rc; char *zErrMsg = 0; sqlite3_stmt *pStmt; g.zArgv0 = argv[0]; sqlite3_config(SQLITE_CONFIG_SINGLETHREAD); for(i=1; i<argc; i++){ const char *z = argv[i]; if( z[0]=='-' ){ z++; if( z[0]=='-' ) z++; if( strcmp(z,"debug")==0 ){ if( i==argc-1 ) cmdlineError("missing argument to %s", argv[i]); g.fDebug = strtol(argv[++i], 0, 0); }else if( strcmp(z,"help")==0 ){ showHelp(); return 0; }else { cmdlineError("unknown option: %s", argv[i]); } }else if( zDb==0 ){ zDb = argv[i]; }else{ cmdlineError("unknown argument: %s", argv[i]); } } if( zDb==0 ){ cmdlineError("database filename required"); } rc = sqlite3_open(zDb, &g.db); if( rc ){ cmdlineError("cannot open database file \"%s\"", zDb); } rc = sqlite3_exec(g.db, "SELECT * FROM sqlite_master", 0, 0, &zErrMsg); if( rc || zErrMsg ){ cmdlineError("\"%s\" does not appear to be a valid SQLite database", zDb); } rc = sqlite3_exec(g.db, "CREATE TEMP TABLE est_stat1(tbl,idx,stat);", 0, 0, &zErrMsg); if( rc || zErrMsg ){ cmdlineError("Cannot CREATE TEMP TABLE"); } pStmt = db_prepare("SELECT type, name, tbl_name FROM sqlite_master" " WHERE type IN ('table','index')" " AND rootpage>0" " AND (type='index' OR name NOT LIKE 'sqlite_%%')" " ORDER BY tbl_name, type DESC, name"); while( sqlite3_step(pStmt)==SQLITE_ROW ){ const char *zType = (const char*)sqlite3_column_text(pStmt, 0); const char *zName = (const char*)sqlite3_column_text(pStmt, 1); const char *zTblName = (const char*)sqlite3_column_text(pStmt, 2); if( zType[0]=='t' ){ analyzeTable(zName); }else{ analyzeIndex(zTblName, zName); } } sqlite3_finalize(pStmt); dump_table("temp.est_stat1","sqlite_stat1"); sqlite3_close(g.db); return 0; } |