Many hyperlinks are disabled.
Use anonymous login
to enable hyperlinks.
Overview
Comment: | Clean up sqlite_stat2 related code. Add test cases. |
---|---|
Downloads: | Tarball | ZIP archive |
Timelines: | family | ancestors | descendants | both | trunk |
Files: | files | file ages | folders |
SHA1: |
aa728e06ce456fa42e68687bff6c7424 |
User & Date: | dan 2009-08-19 14:34:55.000 |
Context
2009-08-19
| ||
14:42 | Merge with 709e16145e. (check-in: 6c8a0e2b37 user: dan tags: trunk) | |
14:34 | Clean up sqlite_stat2 related code. Add test cases. (check-in: aa728e06ce user: dan tags: trunk) | |
09:09 | Fix a problem where a buffer allocated from a lookaside pool was being released using the system free(). (check-in: 67207a15bd user: dan tags: trunk) | |
Changes
Changes to src/analyze.c.
︙ | ︙ | |||
112 113 114 115 116 117 118 | int iIdxCur; /* Cursor open on index being analyzed */ Vdbe *v; /* The virtual machine being built up */ int i; /* Loop counter */ int topOfLoop; /* The top of the loop */ int endOfLoop; /* The end of the loop */ int addr; /* The address of an instruction */ int iDb; /* Index of database containing pTab */ | < < < | 112 113 114 115 116 117 118 119 120 121 122 123 124 125 126 127 128 129 130 131 132 | int iIdxCur; /* Cursor open on index being analyzed */ Vdbe *v; /* The virtual machine being built up */ int i; /* Loop counter */ int topOfLoop; /* The top of the loop */ int endOfLoop; /* The end of the loop */ int addr; /* The address of an instruction */ int iDb; /* Index of database containing pTab */ int regTabname = iMem++; /* Register containing table name */ int regIdxname = iMem++; /* Register containing index name */ int regSampleno = iMem++; /* Register containing next sample number */ int regCol = iMem++; /* Content of a column analyzed table */ int regRec = iMem++; /* Register holding completed record */ int regTemp = iMem++; /* Temporary use register */ int regRowid = iMem++; /* Rowid for the inserted record */ #ifdef SQLITE_ENABLE_STAT2 int regTemp2 = iMem++; /* Temporary use register */ int regSamplerecno = iMem++; /* Next sample index record number */ int regRecno = iMem++; /* Register next index record number */ int regCount = iMem++; /* Total number of records in table */ #endif |
︙ | ︙ | |||
191 192 193 194 195 196 197 | ** all are collected. */ sqlite3VdbeAddOp2(v, OP_Integer, SQLITE_INDEX_SAMPLES, regSamplerecno); sqlite3VdbeAddOp3(v, OP_Lt, regSamplerecno, sqlite3VdbeCurrentAddr(v)+2, regCount); sqlite3VdbeAddOp2(v, OP_Integer, 0, regSamplerecno); #endif | | < < > | > | | | > | < | | | 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 | ** all are collected. */ sqlite3VdbeAddOp2(v, OP_Integer, SQLITE_INDEX_SAMPLES, regSamplerecno); sqlite3VdbeAddOp3(v, OP_Lt, regSamplerecno, sqlite3VdbeCurrentAddr(v)+2, regCount); sqlite3VdbeAddOp2(v, OP_Integer, 0, regSamplerecno); #endif /* The block of memory cells initialized here is used as follows. ** ** iMem: ** The total number of rows in the table. ** ** iMem+1 .. iMem+nCol: ** Number of distinct entries in index considering the ** left-most N columns only, where N is between 1 and nCol, ** inclusive. ** ** iMem+nCol+1 .. Mem+2*nCol: ** Previous value of indexed columns, from left to right. ** ** Cells iMem through iMem+nCol are initialized to 0. The others are ** initialized to contain an SQL NULL. */ for(i=0; i<=nCol; i++){ sqlite3VdbeAddOp2(v, OP_Integer, 0, iMem+i); } for(i=0; i<nCol; i++){ sqlite3VdbeAddOp2(v, OP_Null, 0, iMem+nCol+i+1); } |
︙ | ︙ | |||
253 254 255 256 257 258 259 | sqlite3VdbeAddOp3(v, OP_Subtract, regSampleno, regTemp2, regTemp2); sqlite3VdbeAddOp3(v, OP_Divide, regTemp2, regTemp, regTemp); sqlite3VdbeAddOp3(v, OP_Add, regSamplerecno, regTemp, regSamplerecno); sqlite3VdbeJumpHere(v, ne); sqlite3VdbeAddOp2(v, OP_AddImm, regRecno, 1); } | < < < < < < < | < | 250 251 252 253 254 255 256 257 258 259 260 261 262 263 264 265 266 267 268 269 270 271 272 | sqlite3VdbeAddOp3(v, OP_Subtract, regSampleno, regTemp2, regTemp2); sqlite3VdbeAddOp3(v, OP_Divide, regTemp2, regTemp, regTemp); sqlite3VdbeAddOp3(v, OP_Add, regSamplerecno, regTemp, regSamplerecno); sqlite3VdbeJumpHere(v, ne); sqlite3VdbeAddOp2(v, OP_AddImm, regRecno, 1); } #endif sqlite3VdbeAddOp3(v, OP_Ne, regCol, 0, iMem+nCol+i+1); /**** TODO: add collating sequence *****/ sqlite3VdbeChangeP5(v, SQLITE_JUMPIFNULL); } sqlite3VdbeAddOp2(v, OP_Goto, 0, endOfLoop); for(i=0; i<nCol; i++){ sqlite3VdbeJumpHere(v, sqlite3VdbeCurrentAddr(v)-(nCol*2)); sqlite3VdbeAddOp2(v, OP_AddImm, iMem+i+1, 1); sqlite3VdbeAddOp3(v, OP_Column, iIdxCur, i, iMem+nCol+i+1); } /* End of the analysis loop. */ sqlite3VdbeResolveLabel(v, endOfLoop); sqlite3VdbeAddOp2(v, OP_Next, iIdxCur, topOfLoop); |
︙ | ︙ | |||
482 483 484 485 486 487 488 | pIndex->aiRowEst[i] = v; if( *z==' ' ) z++; } return 0; } /* | > > > > > > > > > > > > > > > > > > > > > | > > > | > > > > > > > > > > > > > > | | | | > > > > | < | | < | | < | | < | > > | | < < < | < | > | 471 472 473 474 475 476 477 478 479 480 481 482 483 484 485 486 487 488 489 490 491 492 493 494 495 496 497 498 499 500 501 502 503 504 505 506 507 508 509 510 511 512 513 514 515 516 517 518 519 520 521 522 523 524 525 526 527 528 529 530 531 532 533 534 535 536 537 538 539 540 541 542 543 544 545 546 547 548 549 550 551 552 553 554 555 556 557 558 559 560 561 562 563 564 565 566 567 568 569 570 571 572 573 574 575 576 577 578 579 580 581 582 583 584 585 586 587 588 589 590 591 592 593 594 595 596 597 598 599 600 601 602 603 604 605 606 607 608 609 610 611 612 613 614 615 616 617 618 619 620 621 622 623 624 625 626 627 628 629 630 631 632 633 634 635 636 | pIndex->aiRowEst[i] = v; if( *z==' ' ) z++; } return 0; } /* ** If the Index.aSample variable is not NULL, delete the aSample[] array ** and its contents. */ void sqlite3DeleteIndexSamples(Index *pIdx){ #ifdef SQLITE_ENABLE_STAT2 if( pIdx->aSample ){ int j; sqlite3 *dbMem = pIdx->pTable->dbMem; for(j=0; j<SQLITE_INDEX_SAMPLES; j++){ IndexSample *p = &pIdx->aSample[j]; if( p->eType==SQLITE_TEXT || p->eType==SQLITE_BLOB ){ sqlite3DbFree(pIdx->pTable->dbMem, p->u.z); } } sqlite3DbFree(dbMem, pIdx->aSample); pIdx->aSample = 0; } #endif } /* ** Load the content of the sqlite_stat1 and sqlite_stat2 tables. The ** contents of sqlite_stat1 are used to populate the Index.aiRowEst[] ** arrays. The contents of sqlite_stat2 are used to populate the ** Index.aSample[] arrays. ** ** If the sqlite_stat1 table is not present in the database, SQLITE_ERROR ** is returned. In this case, even if SQLITE_ENABLE_STAT2 was defined ** during compilation and the sqlite_stat2 table is present, no data is ** read from it. ** ** If SQLITE_ENABLE_STAT2 was defined during compilation and the ** sqlite_stat2 table is not present in the database, SQLITE_ERROR is ** returned. However, in this case, data is read from the sqlite_stat1 ** table (if it is present) before returning. ** ** If an OOM error occurs, this function always sets db->mallocFailed. ** This means if the caller does not care about other errors, the return ** code may be ignored. */ int sqlite3AnalysisLoad(sqlite3 *db, int iDb){ analysisInfo sInfo; HashElem *i; char *zSql; int rc; assert( iDb>=0 && iDb<db->nDb ); assert( db->aDb[iDb].pBt!=0 ); assert( sqlite3BtreeHoldsMutex(db->aDb[iDb].pBt) ); /* Clear any prior statistics */ for(i=sqliteHashFirst(&db->aDb[iDb].pSchema->idxHash);i;i=sqliteHashNext(i)){ Index *pIdx = sqliteHashData(i); sqlite3DefaultRowEst(pIdx); sqlite3DeleteIndexSamples(pIdx); } /* Check to make sure the sqlite_stat1 table exists */ sInfo.db = db; sInfo.zDatabase = db->aDb[iDb].zName; if( sqlite3FindTable(db, "sqlite_stat1", sInfo.zDatabase)==0 ){ return SQLITE_ERROR; } /* Load new statistics out of the sqlite_stat1 table */ zSql = sqlite3MPrintf(db, "SELECT idx, stat FROM %Q.sqlite_stat1", sInfo.zDatabase); if( zSql==0 ){ rc = SQLITE_NOMEM; }else{ (void)sqlite3SafetyOff(db); rc = sqlite3_exec(db, zSql, analysisLoader, &sInfo, 0); (void)sqlite3SafetyOn(db); sqlite3DbFree(db, zSql); } /* Load the statistics from the sqlite_stat2 table. */ #ifdef SQLITE_ENABLE_STAT2 if( rc==SQLITE_OK && !sqlite3FindTable(db, "sqlite_stat2", sInfo.zDatabase) ){ rc = SQLITE_ERROR; } if( rc==SQLITE_OK ){ sqlite3_stmt *pStmt = 0; zSql = sqlite3MPrintf(db, "SELECT idx,sampleno,sample FROM %Q.sqlite_stat2", sInfo.zDatabase); if( !zSql ){ rc = SQLITE_NOMEM; }else{ (void)sqlite3SafetyOff(db); rc = sqlite3_prepare(db, zSql, -1, &pStmt, 0); (void)sqlite3SafetyOn(db); sqlite3DbFree(db, zSql); } if( rc==SQLITE_OK ){ (void)sqlite3SafetyOff(db); while( sqlite3_step(pStmt)==SQLITE_ROW ){ char *zIndex = (char *)sqlite3_column_text(pStmt, 0); Index *pIdx = sqlite3FindIndex(db, zIndex, sInfo.zDatabase); if( pIdx ){ int iSample = sqlite3_column_int(pStmt, 1); sqlite3 *dbMem = pIdx->pTable->dbMem; assert( dbMem==db || dbMem==0 ); if( iSample<SQLITE_INDEX_SAMPLES && iSample>=0 ){ int eType = sqlite3_column_type(pStmt, 2); if( pIdx->aSample==0 ){ static const int sz = sizeof(IndexSample)*SQLITE_INDEX_SAMPLES; pIdx->aSample = (IndexSample *)sqlite3DbMallocZero(dbMem, sz); if( pIdx->aSample==0 ){ db->mallocFailed = 1; break; } } if( pIdx->aSample ){ IndexSample *pSample = &pIdx->aSample[iSample]; pSample->eType = eType; if( eType==SQLITE_INTEGER || eType==SQLITE_FLOAT ){ pSample->u.r = sqlite3_column_double(pStmt, 2); }else if( eType==SQLITE_TEXT || eType==SQLITE_BLOB ){ const char *z = (const char *)( (eType==SQLITE_BLOB) ? sqlite3_column_blob(pStmt, 2): sqlite3_column_text(pStmt, 2) ); int n = sqlite3_column_bytes(pStmt, 2); if( n>24 ){ n = 24; } pSample->nByte = n; pSample->u.z = sqlite3DbMallocRaw(dbMem, n); if( pSample->u.z ){ memcpy(pSample->u.z, z, n); }else{ db->mallocFailed = 1; break; } } } } } } rc = sqlite3_finalize(pStmt); (void)sqlite3SafetyOn(db); } } #endif if( rc==SQLITE_NOMEM ){ db->mallocFailed = 1; } return rc; } #endif /* SQLITE_OMIT_ANALYZE */ |
Changes to src/build.c.
︙ | ︙ | |||
339 340 341 342 343 344 345 | /* ** Reclaim the memory used by an index */ static void freeIndex(Index *p){ sqlite3 *db = p->pTable->dbMem; /* testcase( db==0 ); */ | < < < < < < < < < | | 339 340 341 342 343 344 345 346 347 348 349 350 351 352 353 | /* ** Reclaim the memory used by an index */ static void freeIndex(Index *p){ sqlite3 *db = p->pTable->dbMem; /* testcase( db==0 ); */ sqlite3DeleteIndexSamples(p); sqlite3DbFree(db, p->zColAff); sqlite3DbFree(db, p); } /* ** Remove the given index from the index hash table, and free ** its memory structures. |
︙ | ︙ |
Changes to src/sqliteInt.h.
︙ | ︙ | |||
2829 2830 2831 2832 2833 2834 2835 2836 2837 2838 2839 2840 2841 2842 | CollSeq *sqlite3GetCollSeq(sqlite3*, CollSeq *, const char*); char sqlite3AffinityType(const char*); void sqlite3Analyze(Parse*, Token*, Token*); int sqlite3InvokeBusyHandler(BusyHandler*); int sqlite3FindDb(sqlite3*, Token*); int sqlite3FindDbName(sqlite3 *, const char *); int sqlite3AnalysisLoad(sqlite3*,int iDB); void sqlite3DefaultRowEst(Index*); void sqlite3RegisterLikeFunctions(sqlite3*, int); int sqlite3IsLikeFunction(sqlite3*,Expr*,int*,char*); void sqlite3MinimumFileFormat(Parse*, int, int); void sqlite3SchemaFree(void *); Schema *sqlite3SchemaGet(sqlite3 *, Btree *); int sqlite3SchemaToIndex(sqlite3 *db, Schema *); | > | 2829 2830 2831 2832 2833 2834 2835 2836 2837 2838 2839 2840 2841 2842 2843 | CollSeq *sqlite3GetCollSeq(sqlite3*, CollSeq *, const char*); char sqlite3AffinityType(const char*); void sqlite3Analyze(Parse*, Token*, Token*); int sqlite3InvokeBusyHandler(BusyHandler*); int sqlite3FindDb(sqlite3*, Token*); int sqlite3FindDbName(sqlite3 *, const char *); int sqlite3AnalysisLoad(sqlite3*,int iDB); void sqlite3DeleteIndexSamples(Index*); void sqlite3DefaultRowEst(Index*); void sqlite3RegisterLikeFunctions(sqlite3*, int); int sqlite3IsLikeFunction(sqlite3*,Expr*,int*,char*); void sqlite3MinimumFileFormat(Parse*, int, int); void sqlite3SchemaFree(void *); Schema *sqlite3SchemaGet(sqlite3 *, Btree *); int sqlite3SchemaToIndex(sqlite3 *db, Schema *); |
︙ | ︙ |
Changes to test/analyze2.test.
︙ | ︙ | |||
15 16 17 18 19 20 21 | source $testdir/tester.tcl ifcapable !stat2 { finish_test return } | > > > > > > > > > > > > > > > > > > > > > > > > > > > | | 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 | source $testdir/tester.tcl ifcapable !stat2 { finish_test return } #-------------------------------------------------------------------- # Test organization: # # analyze2-1.*: Tests to verify that ANALYZE creates and populates the # sqlite_stat2 table as expected. # # analyze2-2.*: Test that when a table has two indexes on it and either # index may be used for the scan, the index suggested by # the contents of sqlite_stat2 table is prefered. # # analyze2-3.*: Similar to the previous block of tests, but using tables # that contain a mixture of NULL, numeric, text and blob # values. # # analyze2-4.*: Check that when an indexed column uses a collation other # than BINARY, the collation is taken into account when # using the contents of sqlite_stat2 to estimate the cost # of a range scan. # # analyze2-5.*: Check that collation sequences are used as described above # even when the only available version of the collation # function require UTF-16 encoded arguments. # # analyze2-6.*: Check that the library behaves correctly when one of the # sqlite_stat2 or sqlite_stat1 tables are missing. # proc eqp {sql} { uplevel execsql [list "EXPLAIN QUERY PLAN $sql"] } do_test analyze2-1.1 { execsql { CREATE TABLE t1(x PRIMARY KEY) } for {set i 0} {$i < 1000} {incr i} { execsql { INSERT INTO t1 VALUES($i) } |
︙ | ︙ | |||
39 40 41 42 43 44 45 | t1 sqlite_autoindex_t1_1 4 444 \ t1 sqlite_autoindex_t1_1 5 555 \ t1 sqlite_autoindex_t1_1 6 666 \ t1 sqlite_autoindex_t1_1 7 777 \ t1 sqlite_autoindex_t1_1 8 888 \ t1 sqlite_autoindex_t1_1 9 999 \ ] | < < < > | > < > | | < | | < | | | | < | | | | > > > > > > < < < < < < < > > | | | | | | | > > | | | | < | > > | | | | > > > > > > > > > > > > > > > > > > > > > > > > > > > > > | > > > > > > > > > > > > > > > > > > > > > > | > > > | > > > > > | > > > > | > > > > > > > > > | > > > > > > > | > > > > > > > > > > > | > > > > > > > | > > > > > > > > > > | > > > > > > > > > > | > > > > > | | > | > > > > > | > | 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 | t1 sqlite_autoindex_t1_1 4 444 \ t1 sqlite_autoindex_t1_1 5 555 \ t1 sqlite_autoindex_t1_1 6 666 \ t1 sqlite_autoindex_t1_1 7 777 \ t1 sqlite_autoindex_t1_1 8 888 \ t1 sqlite_autoindex_t1_1 9 999 \ ] do_test analyze2-1.2 { execsql { DELETE FROM t1 WHERe x>9; ANALYZE; SELECT tbl, idx, group_concat(sample, ' ') FROM sqlite_stat2; } } {t1 sqlite_autoindex_t1_1 {0 1 2 3 4 5 6 7 8 9}} do_test analyze2-1.3 { execsql { DELETE FROM t1 WHERE x>5; ANALYZE; SELECT * FROM sqlite_stat2; } } {} do_test analyze2-1.4 { execsql { DELETE FROM t1; ANALYZE; SELECT * FROM sqlite_stat2; } } {} do_test analyze2-2.1 { execsql { BEGIN; DROP TABLE t1; CREATE TABLE t1(x, y); CREATE INDEX t1_x ON t1(x); CREATE INDEX t1_y ON t1(y); } for {set i 0} {$i < 1000} {incr i} { execsql { INSERT INTO t1 VALUES($i, $i) } } execsql COMMIT execsql ANALYZE } {} do_test analyze2-2.2 { eqp "SELECT * FROM t1 WHERE x>500 AND y>700" } {0 0 {TABLE t1 WITH INDEX t1_y}} do_test analyze2-2.3 { eqp "SELECT * FROM t1 WHERE x>700 AND y>500" } {0 0 {TABLE t1 WITH INDEX t1_x}} do_test analyze2-2.3 { eqp "SELECT * FROM t1 WHERE y>700 AND x>500" } {0 0 {TABLE t1 WITH INDEX t1_y}} do_test analyze2-2.4 { eqp "SELECT * FROM t1 WHERE y>500 AND x>700" } {0 0 {TABLE t1 WITH INDEX t1_x}} do_test analyze2-2.5 { eqp "SELECT * FROM t1 WHERE x BETWEEN 100 AND 200 AND y BETWEEN 400 AND 700" } {0 0 {TABLE t1 WITH INDEX t1_x}} do_test analyze2-2.6 { eqp "SELECT * FROM t1 WHERE x BETWEEN 100 AND 500 AND y BETWEEN 400 AND 700" } {0 0 {TABLE t1 WITH INDEX t1_y}} do_test analyze2-2.7 { eqp "SELECT * FROM t1 WHERE x BETWEEN -400 AND -300 AND y BETWEEN 100 AND 300" } {0 0 {TABLE t1 WITH INDEX t1_x}} do_test analyze2-2.8 { eqp "SELECT * FROM t1 WHERE x BETWEEN 100 AND 300 AND y BETWEEN -400 AND -300" } {0 0 {TABLE t1 WITH INDEX t1_y}} do_test analyze2-2.9 { eqp "SELECT * FROM t1 WHERE x BETWEEN 500 AND 100 AND y BETWEEN 100 AND 300" } {0 0 {TABLE t1 WITH INDEX t1_x}} do_test analyze2-2.10 { eqp "SELECT * FROM t1 WHERE x BETWEEN 100 AND 300 AND y BETWEEN 500 AND 100" } {0 0 {TABLE t1 WITH INDEX t1_y}} do_test analyze2-3.1 { set alphabet [list a b c d e f g h i j] execsql BEGIN for {set i 0} {$i < 1000} {incr i} { set str [lindex $alphabet [expr ($i/100)%10]] append str [lindex $alphabet [expr ($i/ 10)%10]] append str [lindex $alphabet [expr ($i/ 1)%10]] execsql { INSERT INTO t1 VALUES($str, $str) } } execsql COMMIT execsql ANALYZE execsql { SELECT tbl,idx,group_concat(sample,' ') FROM sqlite_stat2 WHERE idx = 't1_x' GROUP BY tbl,idx } } {t1 t1_x {0 222 444 666 888 bba ddc ffe hhg jjj}} do_test analyze2-3.2 { execsql { SELECT tbl,idx,group_concat(sample,' ') FROM sqlite_stat2 WHERE idx = 't1_y' GROUP BY tbl,idx } } {t1 t1_y {0 222 444 666 888 bba ddc ffe hhg jjj}} do_test analyze2-3.3 { eqp "SELECT * FROM t1 WHERE x BETWEEN 100 AND 500 AND y BETWEEN 'a' AND 'b'" } {0 0 {TABLE t1 WITH INDEX t1_y}} do_test analyze2-3.4 { eqp "SELECT * FROM t1 WHERE x BETWEEN 100 AND 400 AND y BETWEEN 'a' AND 'h'" } {0 0 {TABLE t1 WITH INDEX t1_x}} do_test analyze2-3.5 { eqp "SELECT * FROM t1 WHERE x<'a' AND y>'h'" } {0 0 {TABLE t1 WITH INDEX t1_y}} do_test analyze2-3.6 { eqp "SELECT * FROM t1 WHERE x<444 AND y>'h'" } {0 0 {TABLE t1 WITH INDEX t1_y}} do_test analyze2-3.7 { eqp "SELECT * FROM t1 WHERE x<221 AND y>'h'" } {0 0 {TABLE t1 WITH INDEX t1_x}} do_test analyze2-4.1 { execsql { CREATE TABLE t3(a COLLATE nocase, b) } execsql { CREATE INDEX t3a ON t3(a) } execsql { CREATE INDEX t3b ON t3(b) } set alphabet [list A b C d E f G h I j] execsql BEGIN for {set i 0} {$i < 1000} {incr i} { set str [lindex $alphabet [expr ($i/100)%10]] append str [lindex $alphabet [expr ($i/ 10)%10]] append str [lindex $alphabet [expr ($i/ 1)%10]] execsql { INSERT INTO t3 VALUES($str, $str) } } execsql COMMIT execsql ANALYZE } {} do_test analyze2-4.2 { execsql { SELECT tbl,idx,group_concat(sample,' ') FROM sqlite_stat2 WHERE idx = 't3a' GROUP BY tbl,idx } } {t3 t3a {AAA bbb CCC ddd EEE fff GGG hhh III jjj}} do_test analyze2-4.3 { execsql { SELECT tbl,idx,group_concat(sample,' ') FROM sqlite_stat2 WHERE idx = 't3b' GROUP BY tbl,idx } } {t3 t3b {AAA CCC EEE GGG III bbb ddd fff hhh jjj}} do_test analyze2-4.4 { eqp "SELECT * FROM t3 WHERE a > 'A' AND a < 'C' AND b > 'A' AND b < 'C'" } {0 0 {TABLE t3 WITH INDEX t3b}} do_test analyze2-4.5 { eqp "SELECT * FROM t3 WHERE a > 'A' AND a < 'c' AND b > 'A' AND b < 'c'" } {0 0 {TABLE t3 WITH INDEX t3a}} proc test_collate {enc lhs rhs} { # puts $enc return [string compare $lhs $rhs] } do_test analyze2-5.1 { add_test_collate db 0 0 1 execsql { CREATE TABLE t4(x COLLATE test_collate) } execsql { CREATE INDEX t4x ON t4(x) } set alphabet [list a b c d e f g h i j] execsql BEGIN for {set i 0} {$i < 1000} {incr i} { set str [lindex $alphabet [expr ($i/100)%10]] append str [lindex $alphabet [expr ($i/ 10)%10]] append str [lindex $alphabet [expr ($i/ 1)%10]] execsql { INSERT INTO t4 VALUES($str) } } execsql COMMIT execsql ANALYZE } {} do_test analyze2-5.2 { execsql { SELECT tbl,idx,group_concat(sample,' ') FROM sqlite_stat2 WHERE tbl = 't4' GROUP BY tbl,idx } } {t4 t4x {aaa bbb ccc ddd eee fff ggg hhh iii jjj}} do_test analyze2-5.3 { eqp "SELECT * FROM t4 WHERE x>'ccc'" } {0 0 {TABLE t4 WITH INDEX t4x}} do_test analyze2-5.4 { eqp "SELECT * FROM t4 AS t41, t4 AS t42 WHERE t41.x>'ccc' AND t42.x>'ggg'" } {0 1 {TABLE t4 AS t42 WITH INDEX t4x} 1 0 {TABLE t4 AS t41 WITH INDEX t4x}} do_test analyze2-5.5 { eqp "SELECT * FROM t4 AS t41, t4 AS t42 WHERE t41.x>'ddd' AND t42.x>'ccc'" } {0 0 {TABLE t4 AS t41 WITH INDEX t4x} 1 1 {TABLE t4 AS t42 WITH INDEX t4x}} #-------------------------------------------------------------------- # These tests, analyze2-6.*, verify that the library behaves correctly # when one of the sqlite_stat1 and sqlite_stat2 tables is missing. # # If the sqlite_stat1 table is not present, then the sqlite_stat2 # table is not read. However, if it is the sqlite_stat2 table that # is missing, the data in the sqlite_stat1 table is still used. # # Tests analyze2-6.1.* test the libary when the sqlite_stat2 table # is missing. Tests analyze2-6.2.* test the library when sqlite_stat1 # is not present. # do_test analyze2-6.0 { execsql { DROP TABLE t4; CREATE TABLE t5(a, b); CREATE INDEX t5i ON t5(a, b); CREATE TABLE t6(a, b); CREATE INDEX t6i ON t6(a, b); } for {set ii 0} {$ii < 20} {incr ii} { execsql { INSERT INTO t5 VALUES($ii, $ii); INSERT INTO t6 VALUES($ii/10, $ii/10); } } execsql { CREATE TABLE master AS SELECT * FROM sqlite_master WHERE name LIKE 'sqlite_stat%' } } {} do_test analyze2-6.1.1 { eqp {SELECT * FROM t5,t6 WHERE t5.rowid=t6.rowid AND t5.a = 1 AND t6.a = 1 AND t6.b = 1 } } {0 1 {TABLE t6 WITH INDEX t6i} 1 0 {TABLE t5 USING PRIMARY KEY}} do_test analyze2-6.1.2 { db cache flush execsql ANALYZE eqp {SELECT * FROM t5,t6 WHERE t5.rowid=t6.rowid AND t5.a = 1 AND t6.a = 1 AND t6.b = 1 } } {0 0 {TABLE t5 WITH INDEX t5i} 1 1 {TABLE t6 USING PRIMARY KEY}} do_test analyze2-6.1.3 { sqlite3 db test.db eqp { SELECT * FROM t5,t6 WHERE t5.rowid=t6.rowid AND t5.a = 1 AND t6.a = 1 AND t6.b = 1 } } {0 0 {TABLE t5 WITH INDEX t5i} 1 1 {TABLE t6 USING PRIMARY KEY}} do_test analyze2-6.1.4 { execsql { PRAGMA writable_schema = 1; DELETE FROM sqlite_master WHERE tbl_name = 'sqlite_stat2'; } sqlite3 db test.db eqp { SELECT * FROM t5,t6 WHERE t5.rowid=t6.rowid AND t5.a = 1 AND t6.a = 1 AND t6.b = 1 } } {0 0 {TABLE t5 WITH INDEX t5i} 1 1 {TABLE t6 USING PRIMARY KEY}} do_test analyze2-6.1.5 { execsql { PRAGMA writable_schema = 1; DELETE FROM sqlite_master WHERE tbl_name = 'sqlite_stat1'; } sqlite3 db test.db eqp { SELECT * FROM t5,t6 WHERE t5.rowid=t6.rowid AND t5.a = 1 AND t6.a = 1 AND t6.b = 1 } } {0 1 {TABLE t6 WITH INDEX t6i} 1 0 {TABLE t5 USING PRIMARY KEY}} do_test analyze2-6.1.6 { execsql { PRAGMA writable_schema = 1; INSERT INTO sqlite_master SELECT * FROM master; } sqlite3 db test.db eqp { SELECT * FROM t5,t6 WHERE t5.rowid=t6.rowid AND t5.a = 1 AND t6.a = 1 AND t6.b = 1 } } {0 0 {TABLE t5 WITH INDEX t5i} 1 1 {TABLE t6 USING PRIMARY KEY}} do_test analyze2-6.2.1 { execsql { DELETE FROM sqlite_stat1; DELETE FROM sqlite_stat2; } sqlite3 db test.db eqp { SELECT * FROM t5,t6 WHERE t5.rowid=t6.rowid AND t5.a>1 AND t5.a<15 AND t6.a>1 } } {0 0 {TABLE t5 WITH INDEX t5i} 1 1 {TABLE t6 USING PRIMARY KEY}} do_test analyze2-6.2.2 { db cache flush execsql ANALYZE eqp { SELECT * FROM t5,t6 WHERE t5.rowid=t6.rowid AND t5.a>1 AND t5.a<15 AND t6.a>1 } } {0 1 {TABLE t6 WITH INDEX t6i} 1 0 {TABLE t5 USING PRIMARY KEY}} do_test analyze2-6.2.3 { sqlite3 db test.db eqp { SELECT * FROM t5,t6 WHERE t5.rowid=t6.rowid AND t5.a>1 AND t5.a<15 AND t6.a>1 } } {0 1 {TABLE t6 WITH INDEX t6i} 1 0 {TABLE t5 USING PRIMARY KEY}} do_test analyze2-6.2.4 { execsql { PRAGMA writable_schema = 1; DELETE FROM sqlite_master WHERE tbl_name = 'sqlite_stat1'; } sqlite3 db test.db eqp { SELECT * FROM t5,t6 WHERE t5.rowid=t6.rowid AND t5.a>1 AND t5.a<15 AND t6.a>1 } } {0 0 {TABLE t5 WITH INDEX t5i} 1 1 {TABLE t6 USING PRIMARY KEY}} do_test analyze2-6.2.5 { execsql { PRAGMA writable_schema = 1; DELETE FROM sqlite_master WHERE tbl_name = 'sqlite_stat2'; } sqlite3 db test.db eqp { SELECT * FROM t5,t6 WHERE t5.rowid=t6.rowid AND t5.a>1 AND t5.a<15 AND t6.a>1 } } {0 0 {TABLE t5 WITH INDEX t5i} 1 1 {TABLE t6 USING PRIMARY KEY}} do_test analyze2-6.2.6 { execsql { PRAGMA writable_schema = 1; INSERT INTO sqlite_master SELECT * FROM master; } sqlite3 db test.db execsql ANALYZE eqp { SELECT * FROM t5,t6 WHERE t5.rowid=t6.rowid AND t5.a>1 AND t5.a<15 AND t6.a>1 } } {0 1 {TABLE t6 WITH INDEX t6i} 1 0 {TABLE t5 USING PRIMARY KEY}} finish_test |
Changes to test/malloc.test.
︙ | ︙ | |||
861 862 863 864 865 866 867 868 869 870 871 872 873 874 | do_test malloc-36.$zRepeat.${::n}.unlocked { execsql {INSERT INTO t1 VALUES(3, 4)} db2 } {} db2 close } catch { db2 close } } # Ensure that no file descriptors were leaked. do_test malloc-99.X { catch {db close} set sqlite_open_file_count } {0} | > > > > > > > > > > > > > > > > > > > > > > > > > > > | 861 862 863 864 865 866 867 868 869 870 871 872 873 874 875 876 877 878 879 880 881 882 883 884 885 886 887 888 889 890 891 892 893 894 895 896 897 898 899 900 901 | do_test malloc-36.$zRepeat.${::n}.unlocked { execsql {INSERT INTO t1 VALUES(3, 4)} db2 } {} db2 close } catch { db2 close } } ifcapable stat2 { do_malloc_test 38 -tclprep { add_test_collate db 0 0 1 execsql { ANALYZE; CREATE TABLE t4(x COLLATE test_collate); CREATE INDEX t4x ON t4(x); INSERT INTO sqlite_stat2 VALUES('t4', 't4x', 0, 'aaa'); INSERT INTO sqlite_stat2 VALUES('t4', 't4x', 1, 'aaa'); INSERT INTO sqlite_stat2 VALUES('t4', 't4x', 2, 'aaa'); INSERT INTO sqlite_stat2 VALUES('t4', 't4x', 3, 'aaa'); INSERT INTO sqlite_stat2 VALUES('t4', 't4x', 4, 'aaa'); INSERT INTO sqlite_stat2 VALUES('t4', 't4x', 5, 'aaa'); INSERT INTO sqlite_stat2 VALUES('t4', 't4x', 6, 'aaa'); INSERT INTO sqlite_stat2 VALUES('t4', 't4x', 7, 'aaa'); INSERT INTO sqlite_stat2 VALUES('t4', 't4x', 8, 'aaa'); INSERT INTO sqlite_stat2 VALUES('t4', 't4x', 9, 'aaa'); } db close sqlite3 db test.db sqlite3_db_config_lookaside db 0 0 0 add_test_collate db 0 0 1 } -sqlbody { SELECT * FROM t4 AS t41, t4 AS t42 WHERE t41.x>'ddd' AND t42.x>'ccc' } } # Ensure that no file descriptors were leaked. do_test malloc-99.X { catch {db close} set sqlite_open_file_count } {0} |
︙ | ︙ |