Merge the stat2 query planner enhancements into the trunk.
FossilOrigin-Name: 499edcbc8ab70fcf35431d4e672c68dbcb6c5aad
This commit is contained in:
commit
47fe5533a6
39
manifest
39
manifest
@ -1,8 +1,8 @@
|
||||
-----BEGIN PGP SIGNED MESSAGE-----
|
||||
Hash: SHA1
|
||||
|
||||
C If\sa\sdeferred\sforeign\skey\sconstraint\sfails\son\sa\sstatement\sthat\sis\snot\spart\nof\sa\slarger\stransation,\smake\ssure\sthat\sthe\sstatement\sfully\sends\sso\sthat\nsubsequent\sinvocations\sof\sthe\ssame\sstatement\swill\snot\spass\sthe\sconstraint\nbecause\sthey\sthink\sthe\stransaction\sis\snot\sclosed.\s\sThis\sis\sa\smerge\sof\nthe\sdeferred-fk-quirk\sbranch\stogether\swith\sa\stest\scase.
|
||||
D 2011-02-04T05:47:51.496
|
||||
C Merge\sthe\sstat2\squery\splanner\senhancements\sinto\sthe\strunk.
|
||||
D 2011-02-04T06:36:44.125
|
||||
F Makefile.arm-wince-mingw32ce-gcc d6df77f1f48d690bd73162294bbba7f59507c72f
|
||||
F Makefile.in de6498556d536ae60bb8bb10e8c1ba011448658c
|
||||
F Makefile.linux-gcc 91d710bdc4998cb015f39edf3cb314ec4f4d7e23
|
||||
@ -238,13 +238,13 @@ F src/vdbeInt.h 6e6f28e9bccc6c703dca1372fd661c57b5c15fb0
|
||||
F src/vdbeapi.c 8e9324fd35eb70d0b5904bd1af40f2598744dc4d
|
||||
F src/vdbeaux.c 521b954f21ec15aee2ba5a0af8a1526bdd71e45e
|
||||
F src/vdbeblob.c 18955f0ee6b133cd08e1592010cb9a6b11e9984c
|
||||
F src/vdbemem.c 411649a35686f54268ccabeda175322c4697f5a6
|
||||
F src/vdbemem.c c011228c6fb1b5df924e4584765b16bde863c9c6
|
||||
F src/vdbetrace.c 3ba13bc32bdf16d2bdea523245fd16736bed67b5
|
||||
F src/vtab.c b297e8fa656ab5e66244ab15680d68db0adbec30
|
||||
F src/wal.c 8704a563b37c0c48b6a65d49da5d5656568abfc6
|
||||
F src/wal.h 7a5fbb00114b7f2cd40c7e1003d4c41ce9d26840
|
||||
F src/walker.c 3112bb3afe1d85dc52317cb1d752055e9a781f8f
|
||||
F src/where.c af069e6b53234118014dabfece96a9515b69d76b
|
||||
F src/where.c f4915ac03e5e42c8416b35ca3ba34af841c00d12
|
||||
F test/aggerror.test a867e273ef9e3d7919f03ef4f0e8c0d2767944f2
|
||||
F test/alias.test 4529fbc152f190268a15f9384a5651bbbabc9d87
|
||||
F test/all.test 51756962d522e474338e9b2ebb26e7364d4aa125
|
||||
@ -254,9 +254,10 @@ F test/alter3.test 8677e48d95536f7a6ed86a1a774744dadcc22b07
|
||||
F test/alter4.test 1e5dd6b951e9f65ca66422edff02e56df82dd403
|
||||
F test/altermalloc.test e81ac9657ed25c6c5bb09bebfa5a047cd8e4acfc
|
||||
F test/analyze.test c1eb87067fc16ece7c07e823d6395fd831b270c5
|
||||
F test/analyze2.test 3bde8f0879d9c1f2df3af21fcf42e706d8ee1e43
|
||||
F test/analyze3.test 820ddfb7591b49607fbaf77240c7955ac3cabb04
|
||||
F test/analyze2.test 8f2b1534d43f5547ce9a6b736c021d4192c75be3
|
||||
F test/analyze3.test d61f55d8b472fc6e713160b1e577f7a68e63f38b
|
||||
F test/analyze4.test 757b37875cf9bb528d46f74497bc789c88365045
|
||||
F test/analyze5.test 18659612dd854330b9f2a0bf4c90658f3739fd67
|
||||
F test/async.test ad4ba51b77cd118911a3fe1356b0809da9c108c3
|
||||
F test/async2.test bf5e2ca2c96763b4cba3d016249ad7259a5603b6
|
||||
F test/async3.test 93edaa9122f498e56ea98c36c72abc407f4fb11e
|
||||
@ -357,7 +358,7 @@ F test/descidx2.test 9f1a0c83fd57f8667c82310ca21b30a350888b5d
|
||||
F test/descidx3.test fe720e8b37d59f4cef808b0bf4e1b391c2e56b6f
|
||||
F test/diskfull.test 0cede7ef9d8f415d9d3944005c76be7589bb5ebb
|
||||
F test/distinctagg.test 1a6ef9c87a58669438fc771450d7a72577417376
|
||||
F test/e_createtable.test b8f5286879315d5b7f4cc5ead1afda4846f0c0bb
|
||||
F test/e_createtable.test b40fc61bc4f1ad2a3c84590bd1d711507263d921
|
||||
F test/e_delete.test 55d868b647acc091c261a10b9b0cb0ab660a6acb
|
||||
F test/e_droptrigger.test ddd4b28ed8a3d81bd5153fa0ab7559529a2ca03a
|
||||
F test/e_dropview.test b347bab30fc8de67b131594b3cd6f3d3bdaa753d
|
||||
@ -375,7 +376,7 @@ F test/enc.test e54531cd6bf941ee6760be041dff19a104c7acea
|
||||
F test/enc2.test 6d91a5286f59add0cfcbb2d0da913b76f2242398
|
||||
F test/enc3.test 5c550d59ff31dccdba5d1a02ae11c7047d77c041
|
||||
F test/enc4.test 4b575ef09e0eff896e73bd24076f96c2aa6a42de
|
||||
F test/eqp.test 69670e7919030f21de29fb99bf1d68f97aedcbdb
|
||||
F test/eqp.test 8f535d902b2df780d22edb95113880480664f976
|
||||
F test/eval.test bc269c365ba877554948441e91ad5373f9f91be3
|
||||
F test/exclusive.test 53e1841b422e554cecf0160f937c473d6d0e3062
|
||||
F test/exclusive2.test b65264c3e76e1db6c6eda15c02000a40743f6541
|
||||
@ -490,7 +491,7 @@ F test/incrvacuum_ioerr.test 57d2f5777ab13fa03b87b262a4ea1bad5cfc0291
|
||||
F test/index.test df7c00c6edd9504ab71c83a9514f1c5ca0fa54d8
|
||||
F test/index2.test ee83c6b5e3173a3d7137140d945d9a5d4fdfb9d6
|
||||
F test/index3.test 423a25c789fc8cc51aaf2a4370bbdde2d9e9eed7
|
||||
F test/indexedby.test d7367c5a0e8ed8db642824a68126753e0808c706
|
||||
F test/indexedby.test be501e381b82b2f8ab406309ba7aac46e221f4ad
|
||||
F test/init.test 15c823093fdabbf7b531fe22cf037134d09587a7
|
||||
F test/insert.test aef273dd1cee84cc92407469e6bd1b3cdcb76908
|
||||
F test/insert2.test 4f3a04d168c728ed5ec2c88842e772606c7ce435
|
||||
@ -521,7 +522,7 @@ F test/jrnlmode3.test c6522b276ba315fd1416198de6fc1da9e72409fb
|
||||
F test/keyword1.test a2400977a2e4fde43bf33754c2929fda34dbca05
|
||||
F test/lastinsert.test 474d519c68cb79d07ecae56a763aa7f322c72f51
|
||||
F test/laststmtchanges.test ae613f53819206b3222771828d024154d51db200
|
||||
F test/like.test 0f64aeaed50b6e3ebaef3af0b3b8f894aed5acca
|
||||
F test/like.test a47f52692aac96ba82508efba74819214cdebc17
|
||||
F test/like2.test 3b2ee13149ba4a8a60b59756f4e5d345573852da
|
||||
F test/limit.test 2db7b3b34fb925b8e847d583d2eb67531d0ce67e
|
||||
F test/loadext.test 0393ce12d9616aa87597dd0ec88181de181f6db0
|
||||
@ -565,7 +566,7 @@ F test/memsubsys1.test 679db68394a5692791737b150852173b3e2fea10
|
||||
F test/memsubsys2.test 72a731225997ad5e8df89fdbeae9224616b6aecc
|
||||
F test/minmax.test 722d80816f7e096bf2c04f4111f1a6c1ba65453d
|
||||
F test/minmax2.test 33504c01a03bd99226144e4b03f7631a274d66e0
|
||||
F test/minmax3.test 66a60eb0f20281b0753249d347c5de0766954cee
|
||||
F test/minmax3.test cc1e8b010136db0d01a6f2a29ba5a9f321034354
|
||||
F test/misc1.test e56baf44656dd68d6475a4b44521045a60241e9b
|
||||
F test/misc2.test a628db7b03e18973e5d446c67696b03de718c9fd
|
||||
F test/misc3.test 72c5dc87a78e7865c5ec7a969fc572913dbe96b6
|
||||
@ -864,14 +865,14 @@ F test/walslow.test d21625e2e99e11c032ce949e8a94661576548933
|
||||
F test/walthread.test a25a393c068a2b42b44333fa3fdaae9072f1617c
|
||||
F test/where.test de337a3fe0a459ec7c93db16a519657a90552330
|
||||
F test/where2.test 43d4becaf5a5df854e6c21d624a1cb84c6904554
|
||||
F test/where3.test 8ebedae552e13fc7f2b4e8df6cbe72a095347400
|
||||
F test/where3.test c81d4ecfaed54e8aef9c1a8a90ac83c9f5c49090
|
||||
F test/where4.test e9b9e2f2f98f00379e6031db6a6fca29bae782a2
|
||||
F test/where5.test fdf66f96d29a064b63eb543e28da4dfdccd81ad2
|
||||
F test/where6.test 5da5a98cec820d488e82708301b96cb8c18a258b
|
||||
F test/where7.test aa4cfcd6f66e2a4ef87b6717327325bf4d547502
|
||||
F test/where8.test a6c740fd286d7883e274e17b6230a9d672a7ab1f
|
||||
F test/where8m.test da346596e19d54f0aba35ebade032a7c47d79739
|
||||
F test/where9.test 7ee38c3fd67e76789a6ec769f62f6433d3d4a5cf
|
||||
F test/where9.test 24f19ad14bb1b831564ced5273e681e495662848
|
||||
F test/whereA.test 24c234263c8fe358f079d5e57d884fb569d2da0a
|
||||
F test/whereB.test 0def95db3bdec220a731c7e4bec5930327c1d8c5
|
||||
F test/wherelimit.test 5e9fd41e79bb2b2d588ed999d641d9c965619b31
|
||||
@ -908,14 +909,14 @@ F tool/speedtest2.tcl ee2149167303ba8e95af97873c575c3e0fab58ff
|
||||
F tool/speedtest8.c 2902c46588c40b55661e471d7a86e4dd71a18224
|
||||
F tool/speedtest8inst1.c 293327bc76823f473684d589a8160bde1f52c14e
|
||||
F tool/vdbe-compress.tcl d70ea6d8a19e3571d7ab8c9b75cba86d1173ff0f
|
||||
P e64e1453a9c204d93de1af92dc0b3ca26762b024 8063197ef141c0c62ba710efdd2b3421fbee4e5d
|
||||
R 69d3f0356b4d8f9e9f40d56c45da6c25
|
||||
P 2f94d4623f9aae1b5bc7041bd85f4e3a7462c60e a2a9f6401c927f6259cda3ba35219cabef24e84d
|
||||
R 654ce4e6cf2cefef95b0b26439b60214
|
||||
U drh
|
||||
Z 9ed074a22966ce70581904f84a2ffc62
|
||||
Z 53e699a32a3e2a35635c3c7b5d97adbf
|
||||
-----BEGIN PGP SIGNATURE-----
|
||||
Version: GnuPG v1.4.10 (Darwin)
|
||||
|
||||
iEYEARECAAYFAk1LkwcACgkQoxKgR168RlE5awCdFnaZrUhXoj6KrFZElnyy4f9M
|
||||
kbMAn19H8xD5tiM5UH35kU9mL5D0eNXv
|
||||
=9S5i
|
||||
iEYEARECAAYFAk1LnnwACgkQoxKgR168RlGb5gCdHxqynC2kEpWU39CHtpPLNzYl
|
||||
tuEAnRuLHTKqjeTXUQlltmCERn2tuJ1n
|
||||
=tbOv
|
||||
-----END PGP SIGNATURE-----
|
||||
|
@ -1 +1 @@
|
||||
2f94d4623f9aae1b5bc7041bd85f4e3a7462c60e
|
||||
499edcbc8ab70fcf35431d4e672c68dbcb6c5aad
|
@ -1082,6 +1082,8 @@ int sqlite3ValueFromExpr(
|
||||
pVal->r = (double)-1 * pVal->r;
|
||||
sqlite3ValueApplyAffinity(pVal, affinity, enc);
|
||||
}
|
||||
}else if( op==TK_NULL ){
|
||||
pVal = sqlite3ValueNew(db);
|
||||
}
|
||||
#ifndef SQLITE_OMIT_BLOB_LITERAL
|
||||
else if( op==TK_BLOB ){
|
||||
|
405
src/where.c
405
src/where.c
@ -117,6 +117,7 @@ struct WhereTerm {
|
||||
#define TERM_ORINFO 0x10 /* Need to free the WhereTerm.u.pOrInfo object */
|
||||
#define TERM_ANDINFO 0x20 /* Need to free the WhereTerm.u.pAndInfo obj */
|
||||
#define TERM_OR_OK 0x40 /* Used during OR-clause processing */
|
||||
#define TERM_VNULL 0x80 /* Manufactured x>NULL or x<=NULL term */
|
||||
|
||||
/*
|
||||
** An instance of the following structure holds all information about a
|
||||
@ -210,6 +211,7 @@ struct WhereCost {
|
||||
#define WO_ISNULL 0x080
|
||||
#define WO_OR 0x100 /* Two or more OR-connected terms */
|
||||
#define WO_AND 0x200 /* Two or more AND-connected terms */
|
||||
#define WO_NOOP 0x800 /* This term does not restrict search space */
|
||||
|
||||
#define WO_ALL 0xfff /* Mask of all possible WO_* values */
|
||||
#define WO_SINGLE 0x0ff /* Mask of all non-compound WO_* values */
|
||||
@ -1060,7 +1062,7 @@ static void exprAnalyzeOrTerm(
|
||||
}else{
|
||||
sqlite3ExprListDelete(db, pList);
|
||||
}
|
||||
pTerm->eOperator = 0; /* case 1 trumps case 2 */
|
||||
pTerm->eOperator = WO_NOOP; /* case 1 trumps case 2 */
|
||||
}
|
||||
}
|
||||
}
|
||||
@ -1324,6 +1326,42 @@ static void exprAnalyze(
|
||||
}
|
||||
#endif /* SQLITE_OMIT_VIRTUALTABLE */
|
||||
|
||||
#ifdef SQLITE_ENABLE_STAT2
|
||||
/* When sqlite_stat2 histogram data is available an operator of the
|
||||
** form "x IS NOT NULL" can sometimes be evaluated more efficiently
|
||||
** as "x>NULL" if x is not an INTEGER PRIMARY KEY. So construct a
|
||||
** virtual term of that form.
|
||||
**
|
||||
** Note that the virtual term must be tagged with TERM_VNULL. This
|
||||
** TERM_VNULL tag will suppress the not-null check at the beginning
|
||||
** of the loop. Without the TERM_VNULL flag, the not-null check at
|
||||
** the start of the loop will prevent any results from being returned.
|
||||
*/
|
||||
if( pExpr->op==TK_NOTNULL && pExpr->pLeft->iColumn>=0 ){
|
||||
Expr *pNewExpr;
|
||||
Expr *pLeft = pExpr->pLeft;
|
||||
int idxNew;
|
||||
WhereTerm *pNewTerm;
|
||||
|
||||
pNewExpr = sqlite3PExpr(pParse, TK_GT,
|
||||
sqlite3ExprDup(db, pLeft, 0),
|
||||
sqlite3PExpr(pParse, TK_NULL, 0, 0, 0), 0);
|
||||
|
||||
idxNew = whereClauseInsert(pWC, pNewExpr,
|
||||
TERM_VIRTUAL|TERM_DYNAMIC|TERM_VNULL);
|
||||
testcase( idxNew==0 );
|
||||
pNewTerm = &pWC->a[idxNew];
|
||||
pNewTerm->leftCursor = pLeft->iTable;
|
||||
pNewTerm->u.leftColumn = pLeft->iColumn;
|
||||
pNewTerm->eOperator = WO_GT;
|
||||
pNewTerm->iParent = idxTerm;
|
||||
pTerm = &pWC->a[idxTerm];
|
||||
pTerm->nChild = 1;
|
||||
pTerm->wtFlags |= TERM_COPIED;
|
||||
pNewTerm->prereqAll = pTerm->prereqAll;
|
||||
}
|
||||
#endif /* SQLITE_ENABLE_STAT2 */
|
||||
|
||||
/* Prevent ON clause terms of a LEFT JOIN from being used to drive
|
||||
** an index for tables to the left of the join.
|
||||
*/
|
||||
@ -2201,11 +2239,18 @@ static void bestVirtualIndex(
|
||||
/*
|
||||
** Argument pIdx is a pointer to an index structure that has an array of
|
||||
** SQLITE_INDEX_SAMPLES evenly spaced samples of the first indexed column
|
||||
** stored in Index.aSample. The domain of values stored in said column
|
||||
** may be thought of as divided into (SQLITE_INDEX_SAMPLES+1) regions.
|
||||
** Region 0 contains all values smaller than the first sample value. Region
|
||||
** 1 contains values larger than or equal to the value of the first sample,
|
||||
** but smaller than the value of the second. And so on.
|
||||
** stored in Index.aSample. These samples divide the domain of values stored
|
||||
** the index into (SQLITE_INDEX_SAMPLES+1) regions.
|
||||
** Region 0 contains all values less than the first sample value. Region
|
||||
** 1 contains values between the first and second samples. Region 2 contains
|
||||
** values between samples 2 and 3. And so on. Region SQLITE_INDEX_SAMPLES
|
||||
** contains values larger than the last sample.
|
||||
**
|
||||
** If the index contains many duplicates of a single value, then it is
|
||||
** possible that two or more adjacent samples can hold the same value.
|
||||
** When that is the case, the smallest possible region code is returned
|
||||
** when roundUp is false and the largest possible region code is returned
|
||||
** when roundUp is true.
|
||||
**
|
||||
** If successful, this function determines which of the regions value
|
||||
** pVal lies in, sets *piRegion to the region index (a value between 0
|
||||
@ -2218,8 +2263,10 @@ static int whereRangeRegion(
|
||||
Parse *pParse, /* Database connection */
|
||||
Index *pIdx, /* Index to consider domain of */
|
||||
sqlite3_value *pVal, /* Value to consider */
|
||||
int roundUp, /* Return largest valid region if true */
|
||||
int *piRegion /* OUT: Region of domain in which value lies */
|
||||
){
|
||||
assert( roundUp==0 || roundUp==1 );
|
||||
if( ALWAYS(pVal) ){
|
||||
IndexSample *aSample = pIdx->aSample;
|
||||
int i = 0;
|
||||
@ -2229,7 +2276,17 @@ static int whereRangeRegion(
|
||||
double r = sqlite3_value_double(pVal);
|
||||
for(i=0; i<SQLITE_INDEX_SAMPLES; i++){
|
||||
if( aSample[i].eType==SQLITE_NULL ) continue;
|
||||
if( aSample[i].eType>=SQLITE_TEXT || aSample[i].u.r>r ) break;
|
||||
if( aSample[i].eType>=SQLITE_TEXT ) break;
|
||||
if( roundUp ){
|
||||
if( aSample[i].u.r>r ) break;
|
||||
}else{
|
||||
if( aSample[i].u.r>=r ) break;
|
||||
}
|
||||
}
|
||||
}else if( eType==SQLITE_NULL ){
|
||||
i = 0;
|
||||
if( roundUp ){
|
||||
while( i<SQLITE_INDEX_SAMPLES && aSample[i].eType==SQLITE_NULL ) i++;
|
||||
}
|
||||
}else{
|
||||
sqlite3 *db = pParse->db;
|
||||
@ -2260,7 +2317,7 @@ static int whereRangeRegion(
|
||||
n = sqlite3ValueBytes(pVal, pColl->enc);
|
||||
|
||||
for(i=0; i<SQLITE_INDEX_SAMPLES; i++){
|
||||
int r;
|
||||
int c;
|
||||
int eSampletype = aSample[i].eType;
|
||||
if( eSampletype==SQLITE_NULL || eSampletype<eType ) continue;
|
||||
if( (eSampletype!=eType) ) break;
|
||||
@ -2274,14 +2331,14 @@ static int whereRangeRegion(
|
||||
assert( db->mallocFailed );
|
||||
return SQLITE_NOMEM;
|
||||
}
|
||||
r = pColl->xCmp(pColl->pUser, nSample, zSample, n, z);
|
||||
c = pColl->xCmp(pColl->pUser, nSample, zSample, n, z);
|
||||
sqlite3DbFree(db, zSample);
|
||||
}else
|
||||
#endif
|
||||
{
|
||||
r = pColl->xCmp(pColl->pUser, aSample[i].nByte, aSample[i].u.z, n, z);
|
||||
c = pColl->xCmp(pColl->pUser, aSample[i].nByte, aSample[i].u.z, n, z);
|
||||
}
|
||||
if( r>0 ) break;
|
||||
if( c-roundUp>=0 ) break;
|
||||
}
|
||||
}
|
||||
|
||||
@ -2364,9 +2421,9 @@ static int valueFromExpr(
|
||||
** constraints.
|
||||
**
|
||||
** In the absence of sqlite_stat2 ANALYZE data, each range inequality
|
||||
** reduces the search space by 2/3rds. Hence a single constraint (x>?)
|
||||
** results in a return of 33 and a range constraint (x>? AND x<?) results
|
||||
** in a return of 11.
|
||||
** reduces the search space by 3/4ths. Hence a single constraint (x>?)
|
||||
** results in a return of 25 and a range constraint (x>? AND x<?) results
|
||||
** in a return of 6.
|
||||
*/
|
||||
static int whereRangeScanEst(
|
||||
Parse *pParse, /* Parsing & code generating context */
|
||||
@ -2386,15 +2443,21 @@ static int whereRangeScanEst(
|
||||
int iEst;
|
||||
int iLower = 0;
|
||||
int iUpper = SQLITE_INDEX_SAMPLES;
|
||||
int roundUpUpper;
|
||||
int roundUpLower;
|
||||
u8 aff = p->pTable->aCol[p->aiColumn[0]].affinity;
|
||||
|
||||
if( pLower ){
|
||||
Expr *pExpr = pLower->pExpr->pRight;
|
||||
rc = valueFromExpr(pParse, pExpr, aff, &pLowerVal);
|
||||
assert( pLower->eOperator==WO_GT || pLower->eOperator==WO_GE );
|
||||
roundUpLower = (pLower->eOperator==WO_GT) ?1:0;
|
||||
}
|
||||
if( rc==SQLITE_OK && pUpper ){
|
||||
Expr *pExpr = pUpper->pExpr->pRight;
|
||||
rc = valueFromExpr(pParse, pExpr, aff, &pUpperVal);
|
||||
assert( pUpper->eOperator==WO_LT || pUpper->eOperator==WO_LE );
|
||||
roundUpUpper = (pUpper->eOperator==WO_LE) ?1:0;
|
||||
}
|
||||
|
||||
if( rc!=SQLITE_OK || (pLowerVal==0 && pUpperVal==0) ){
|
||||
@ -2402,28 +2465,29 @@ static int whereRangeScanEst(
|
||||
sqlite3ValueFree(pUpperVal);
|
||||
goto range_est_fallback;
|
||||
}else if( pLowerVal==0 ){
|
||||
rc = whereRangeRegion(pParse, p, pUpperVal, &iUpper);
|
||||
rc = whereRangeRegion(pParse, p, pUpperVal, roundUpUpper, &iUpper);
|
||||
if( pLower ) iLower = iUpper/2;
|
||||
}else if( pUpperVal==0 ){
|
||||
rc = whereRangeRegion(pParse, p, pLowerVal, &iLower);
|
||||
rc = whereRangeRegion(pParse, p, pLowerVal, roundUpLower, &iLower);
|
||||
if( pUpper ) iUpper = (iLower + SQLITE_INDEX_SAMPLES + 1)/2;
|
||||
}else{
|
||||
rc = whereRangeRegion(pParse, p, pUpperVal, &iUpper);
|
||||
rc = whereRangeRegion(pParse, p, pUpperVal, roundUpUpper, &iUpper);
|
||||
if( rc==SQLITE_OK ){
|
||||
rc = whereRangeRegion(pParse, p, pLowerVal, &iLower);
|
||||
rc = whereRangeRegion(pParse, p, pLowerVal, roundUpLower, &iLower);
|
||||
}
|
||||
}
|
||||
WHERETRACE(("range scan regions: %d..%d\n", iLower, iUpper));
|
||||
|
||||
iEst = iUpper - iLower;
|
||||
testcase( iEst==SQLITE_INDEX_SAMPLES );
|
||||
assert( iEst<=SQLITE_INDEX_SAMPLES );
|
||||
if( iEst<1 ){
|
||||
iEst = 1;
|
||||
*piEst = 50/SQLITE_INDEX_SAMPLES;
|
||||
}else{
|
||||
*piEst = (iEst*100)/SQLITE_INDEX_SAMPLES;
|
||||
}
|
||||
|
||||
sqlite3ValueFree(pLowerVal);
|
||||
sqlite3ValueFree(pUpperVal);
|
||||
*piEst = (iEst * 100)/SQLITE_INDEX_SAMPLES;
|
||||
return rc;
|
||||
}
|
||||
range_est_fallback:
|
||||
@ -2433,22 +2497,151 @@ range_est_fallback:
|
||||
UNUSED_PARAMETER(nEq);
|
||||
#endif
|
||||
assert( pLower || pUpper );
|
||||
if( pLower && pUpper ){
|
||||
*piEst = 11;
|
||||
}else{
|
||||
*piEst = 33;
|
||||
}
|
||||
*piEst = 100;
|
||||
if( pLower && (pLower->wtFlags & TERM_VNULL)==0 ) *piEst /= 4;
|
||||
if( pUpper ) *piEst /= 4;
|
||||
return rc;
|
||||
}
|
||||
|
||||
#ifdef SQLITE_ENABLE_STAT2
|
||||
/*
|
||||
** Estimate the number of rows that will be returned based on
|
||||
** an equality constraint x=VALUE and where that VALUE occurs in
|
||||
** the histogram data. This only works when x is the left-most
|
||||
** column of an index and sqlite_stat2 histogram data is available
|
||||
** for that index.
|
||||
**
|
||||
** Write the estimated row count into *pnRow and return SQLITE_OK.
|
||||
** If unable to make an estimate, leave *pnRow unchanged and return
|
||||
** non-zero.
|
||||
**
|
||||
** This routine can fail if it is unable to load a collating sequence
|
||||
** required for string comparison, or if unable to allocate memory
|
||||
** for a UTF conversion required for comparison. The error is stored
|
||||
** in the pParse structure.
|
||||
*/
|
||||
int whereEqualScanEst(
|
||||
Parse *pParse, /* Parsing & code generating context */
|
||||
Index *p, /* The index whose left-most column is pTerm */
|
||||
Expr *pExpr, /* Expression for VALUE in the x=VALUE constraint */
|
||||
double *pnRow /* Write the revised row estimate here */
|
||||
){
|
||||
sqlite3_value *pRhs = 0; /* VALUE on right-hand side of pTerm */
|
||||
int iLower, iUpper; /* Range of histogram regions containing pRhs */
|
||||
u8 aff; /* Column affinity */
|
||||
int rc; /* Subfunction return code */
|
||||
double nRowEst; /* New estimate of the number of rows */
|
||||
|
||||
assert( p->aSample!=0 );
|
||||
aff = p->pTable->aCol[p->aiColumn[0]].affinity;
|
||||
rc = valueFromExpr(pParse, pExpr, aff, &pRhs);
|
||||
if( rc ) goto whereEqualScanEst_cancel;
|
||||
if( pRhs==0 ) return SQLITE_NOTFOUND;
|
||||
rc = whereRangeRegion(pParse, p, pRhs, 0, &iLower);
|
||||
if( rc ) goto whereEqualScanEst_cancel;
|
||||
rc = whereRangeRegion(pParse, p, pRhs, 1, &iUpper);
|
||||
if( rc ) goto whereEqualScanEst_cancel;
|
||||
WHERETRACE(("equality scan regions: %d..%d\n", iLower, iUpper));
|
||||
if( iLower>=iUpper ){
|
||||
nRowEst = p->aiRowEst[0]/(SQLITE_INDEX_SAMPLES*2);
|
||||
if( nRowEst<*pnRow ) *pnRow = nRowEst;
|
||||
}else{
|
||||
nRowEst = (iUpper-iLower)*p->aiRowEst[0]/SQLITE_INDEX_SAMPLES;
|
||||
*pnRow = nRowEst;
|
||||
}
|
||||
|
||||
whereEqualScanEst_cancel:
|
||||
sqlite3ValueFree(pRhs);
|
||||
return rc;
|
||||
}
|
||||
#endif /* defined(SQLITE_ENABLE_STAT2) */
|
||||
|
||||
#ifdef SQLITE_ENABLE_STAT2
|
||||
/*
|
||||
** Estimate the number of rows that will be returned based on
|
||||
** an IN constraint where the right-hand side of the IN operator
|
||||
** is a list of values. Example:
|
||||
**
|
||||
** WHERE x IN (1,2,3,4)
|
||||
**
|
||||
** Write the estimated row count into *pnRow and return SQLITE_OK.
|
||||
** If unable to make an estimate, leave *pnRow unchanged and return
|
||||
** non-zero.
|
||||
**
|
||||
** This routine can fail if it is unable to load a collating sequence
|
||||
** required for string comparison, or if unable to allocate memory
|
||||
** for a UTF conversion required for comparison. The error is stored
|
||||
** in the pParse structure.
|
||||
*/
|
||||
int whereInScanEst(
|
||||
Parse *pParse, /* Parsing & code generating context */
|
||||
Index *p, /* The index whose left-most column is pTerm */
|
||||
ExprList *pList, /* The value list on the RHS of "x IN (v1,v2,v3,...)" */
|
||||
double *pnRow /* Write the revised row estimate here */
|
||||
){
|
||||
sqlite3_value *pVal = 0; /* One value from list */
|
||||
int iLower, iUpper; /* Range of histogram regions containing pRhs */
|
||||
u8 aff; /* Column affinity */
|
||||
int rc = SQLITE_OK; /* Subfunction return code */
|
||||
double nRowEst; /* New estimate of the number of rows */
|
||||
int nSpan = 0; /* Number of histogram regions spanned */
|
||||
int nSingle = 0; /* Histogram regions hit by a single value */
|
||||
int nNotFound = 0; /* Count of values that are not constants */
|
||||
int i; /* Loop counter */
|
||||
u8 aSpan[SQLITE_INDEX_SAMPLES+1]; /* Histogram regions that are spanned */
|
||||
u8 aSingle[SQLITE_INDEX_SAMPLES+1]; /* Histogram regions hit once */
|
||||
|
||||
assert( p->aSample!=0 );
|
||||
aff = p->pTable->aCol[p->aiColumn[0]].affinity;
|
||||
memset(aSpan, 0, sizeof(aSpan));
|
||||
memset(aSingle, 0, sizeof(aSingle));
|
||||
for(i=0; i<pList->nExpr; i++){
|
||||
sqlite3ValueFree(pVal);
|
||||
rc = valueFromExpr(pParse, pList->a[i].pExpr, aff, &pVal);
|
||||
if( rc ) break;
|
||||
if( pVal==0 || sqlite3_value_type(pVal)==SQLITE_NULL ){
|
||||
nNotFound++;
|
||||
continue;
|
||||
}
|
||||
rc = whereRangeRegion(pParse, p, pVal, 0, &iLower);
|
||||
if( rc ) break;
|
||||
rc = whereRangeRegion(pParse, p, pVal, 1, &iUpper);
|
||||
if( rc ) break;
|
||||
if( iLower>=iUpper ){
|
||||
aSingle[iLower] = 1;
|
||||
}else{
|
||||
assert( iLower>=0 && iUpper<=SQLITE_INDEX_SAMPLES );
|
||||
while( iLower<iUpper ) aSpan[iLower++] = 1;
|
||||
}
|
||||
}
|
||||
if( rc==SQLITE_OK ){
|
||||
for(i=nSpan=0; i<=SQLITE_INDEX_SAMPLES; i++){
|
||||
if( aSpan[i] ){
|
||||
nSpan++;
|
||||
}else if( aSingle[i] ){
|
||||
nSingle++;
|
||||
}
|
||||
}
|
||||
nRowEst = (nSpan*2+nSingle)*p->aiRowEst[0]/(2*SQLITE_INDEX_SAMPLES)
|
||||
+ nNotFound*p->aiRowEst[1];
|
||||
if( nRowEst > p->aiRowEst[0] ) nRowEst = p->aiRowEst[0];
|
||||
*pnRow = nRowEst;
|
||||
WHERETRACE(("IN row estimate: nSpan=%d, nSingle=%d, nNotFound=%d, est=%g\n",
|
||||
nSpan, nSingle, nNotFound, nRowEst));
|
||||
}
|
||||
sqlite3ValueFree(pVal);
|
||||
return rc;
|
||||
}
|
||||
#endif /* defined(SQLITE_ENABLE_STAT2) */
|
||||
|
||||
|
||||
/*
|
||||
** Find the query plan for accessing a particular table. Write the
|
||||
** Find the best query plan for accessing a particular table. Write the
|
||||
** best query plan and its cost into the WhereCost object supplied as the
|
||||
** last parameter.
|
||||
**
|
||||
** The lowest cost plan wins. The cost is an estimate of the amount of
|
||||
** CPU and disk I/O need to process the request using the selected plan.
|
||||
** CPU and disk I/O needed to process the requested result.
|
||||
** Factors that influence cost include:
|
||||
**
|
||||
** * The estimated number of rows that will be retrieved. (The
|
||||
@ -2467,7 +2660,7 @@ range_est_fallback:
|
||||
**
|
||||
** If a NOT INDEXED clause (pSrc->notIndexed!=0) was attached to the table
|
||||
** in the SELECT statement, then no indexes are considered. However, the
|
||||
** selected plan may still take advantage of the tables built-in rowid
|
||||
** selected plan may still take advantage of the built-in rowid primary key
|
||||
** index.
|
||||
*/
|
||||
static void bestBtreeIndex(
|
||||
@ -2510,9 +2703,11 @@ static void bestBtreeIndex(
|
||||
wsFlagMask = ~(WHERE_ROWID_EQ|WHERE_ROWID_RANGE);
|
||||
eqTermMask = idxEqTermMask;
|
||||
}else{
|
||||
/* There is no INDEXED BY clause. Create a fake Index object to
|
||||
** represent the primary key */
|
||||
Index *pFirst; /* Any other index on the table */
|
||||
/* There is no INDEXED BY clause. Create a fake Index object in local
|
||||
** variable sPk to represent the rowid primary key index. Make this
|
||||
** fake index the first in a chain of Index objects with all of the real
|
||||
** indices to follow */
|
||||
Index *pFirst; /* First of real indices on the table */
|
||||
memset(&sPk, 0, sizeof(Index));
|
||||
sPk.nColumn = 1;
|
||||
sPk.aiColumn = &aiColumnPk;
|
||||
@ -2523,6 +2718,8 @@ static void bestBtreeIndex(
|
||||
aiRowEstPk[1] = 1;
|
||||
pFirst = pSrc->pTab->pIndex;
|
||||
if( pSrc->notIndexed==0 ){
|
||||
/* The real indices of the table are only considered if the
|
||||
** NOT INDEXED qualifier is omitted from the FROM clause */
|
||||
sPk.pNext = pFirst;
|
||||
}
|
||||
pProbe = &sPk;
|
||||
@ -2540,15 +2737,18 @@ static void bestBtreeIndex(
|
||||
double cost; /* Cost of using pProbe */
|
||||
double nRow; /* Estimated number of rows in result set */
|
||||
int rev; /* True to scan in reverse order */
|
||||
double nSearch; /* Estimated number of binary searches */
|
||||
int wsFlags = 0;
|
||||
Bitmask used = 0;
|
||||
|
||||
/* The following variables are populated based on the properties of
|
||||
** scan being evaluated. They are then used to determine the expected
|
||||
** index being evaluated. They are then used to determine the expected
|
||||
** cost and number of rows returned.
|
||||
**
|
||||
** nEq:
|
||||
** Number of equality terms that can be implemented using the index.
|
||||
** In other words, the number of initial fields in the index that
|
||||
** are used in == or IN or NOT NULL constraints of the WHERE clause.
|
||||
**
|
||||
** nInMul:
|
||||
** The "in-multiplier". This is an estimate of how many seek operations
|
||||
@ -2572,7 +2772,9 @@ static void bestBtreeIndex(
|
||||
**
|
||||
** bInEst:
|
||||
** Set to true if there was at least one "x IN (SELECT ...)" term used
|
||||
** in determining the value of nInMul.
|
||||
** in determining the value of nInMul. Note that the RHS of the
|
||||
** IN operator must be a SELECT, not a value list, for this variable
|
||||
** to be true.
|
||||
**
|
||||
** estBound:
|
||||
** An estimate on the amount of the table that must be searched. A
|
||||
@ -2580,8 +2782,8 @@ static void bestBtreeIndex(
|
||||
** might reduce this to a value less than 100 to indicate that only
|
||||
** a fraction of the table needs searching. In the absence of
|
||||
** sqlite_stat2 ANALYZE data, a single inequality reduces the search
|
||||
** space to 1/3rd its original size. So an x>? constraint reduces
|
||||
** estBound to 33. Two constraints (x>? AND x<?) reduce estBound to 11.
|
||||
** space to 1/4rd its original size. So an x>? constraint reduces
|
||||
** estBound to 25. Two constraints (x>? AND x<?) reduce estBound to 6.
|
||||
**
|
||||
** bSort:
|
||||
** Boolean. True if there is an ORDER BY clause that will require an
|
||||
@ -2589,25 +2791,31 @@ static void bestBtreeIndex(
|
||||
** correctly order records).
|
||||
**
|
||||
** bLookup:
|
||||
** Boolean. True if for each index entry visited a lookup on the
|
||||
** corresponding table b-tree is required. This is always false
|
||||
** for the rowid index. For other indexes, it is true unless all the
|
||||
** columns of the table used by the SELECT statement are present in
|
||||
** the index (such an index is sometimes described as a covering index).
|
||||
** Boolean. True if a table lookup is required for each index entry
|
||||
** visited. In other words, true if this is not a covering index.
|
||||
** This is always false for the rowid primary key index of a table.
|
||||
** For other indexes, it is true unless all the columns of the table
|
||||
** used by the SELECT statement are present in the index (such an
|
||||
** index is sometimes described as a covering index).
|
||||
** For example, given the index on (a, b), the second of the following
|
||||
** two queries requires table b-tree lookups, but the first does not.
|
||||
** two queries requires table b-tree lookups in order to find the value
|
||||
** of column c, but the first does not because columns a and b are
|
||||
** both available in the index.
|
||||
**
|
||||
** SELECT a, b FROM tbl WHERE a = 1;
|
||||
** SELECT a, b, c FROM tbl WHERE a = 1;
|
||||
*/
|
||||
int nEq;
|
||||
int bInEst = 0;
|
||||
int nInMul = 1;
|
||||
int estBound = 100;
|
||||
int nBound = 0; /* Number of range constraints seen */
|
||||
int bSort = 0;
|
||||
int bLookup = 0;
|
||||
WhereTerm *pTerm; /* A single term of the WHERE clause */
|
||||
int nEq; /* Number of == or IN terms matching index */
|
||||
int bInEst = 0; /* True if "x IN (SELECT...)" seen */
|
||||
int nInMul = 1; /* Number of distinct equalities to lookup */
|
||||
int estBound = 100; /* Estimated reduction in search space */
|
||||
int nBound = 0; /* Number of range constraints seen */
|
||||
int bSort = 0; /* True if external sort required */
|
||||
int bLookup = 0; /* True if not a covering index */
|
||||
WhereTerm *pTerm; /* A single term of the WHERE clause */
|
||||
#ifdef SQLITE_ENABLE_STAT2
|
||||
WhereTerm *pFirstTerm = 0; /* First term matching the index */
|
||||
#endif
|
||||
|
||||
/* Determine the values of nEq and nInMul */
|
||||
for(nEq=0; nEq<pProbe->nColumn; nEq++){
|
||||
@ -2619,14 +2827,19 @@ static void bestBtreeIndex(
|
||||
Expr *pExpr = pTerm->pExpr;
|
||||
wsFlags |= WHERE_COLUMN_IN;
|
||||
if( ExprHasProperty(pExpr, EP_xIsSelect) ){
|
||||
/* "x IN (SELECT ...)": Assume the SELECT returns 25 rows */
|
||||
nInMul *= 25;
|
||||
bInEst = 1;
|
||||
}else if( ALWAYS(pExpr->x.pList) ){
|
||||
nInMul *= pExpr->x.pList->nExpr + 1;
|
||||
}else if( ALWAYS(pExpr->x.pList && pExpr->x.pList->nExpr) ){
|
||||
/* "x IN (value, value, ...)" */
|
||||
nInMul *= pExpr->x.pList->nExpr;
|
||||
}
|
||||
}else if( pTerm->eOperator & WO_ISNULL ){
|
||||
wsFlags |= WHERE_COLUMN_NULL;
|
||||
}
|
||||
#ifdef SQLITE_ENABLE_STAT2
|
||||
if( nEq==0 && pProbe->aSample ) pFirstTerm = pTerm;
|
||||
#endif
|
||||
used |= pTerm->prereqRight;
|
||||
}
|
||||
|
||||
@ -2694,8 +2907,8 @@ static void bestBtreeIndex(
|
||||
}
|
||||
|
||||
/*
|
||||
** Estimate the number of rows of output. For an IN operator,
|
||||
** do not let the estimate exceed half the rows in the table.
|
||||
** Estimate the number of rows of output. For an "x IN (SELECT...)"
|
||||
** constraint, do not let the estimate exceed half the rows in the table.
|
||||
*/
|
||||
nRow = (double)(aiRowEst[nEq] * nInMul);
|
||||
if( bInEst && nRow*2>aiRowEst[0] ){
|
||||
@ -2703,31 +2916,69 @@ static void bestBtreeIndex(
|
||||
nInMul = (int)(nRow / aiRowEst[nEq]);
|
||||
}
|
||||
|
||||
/* Assume constant cost to access a row and logarithmic cost to
|
||||
** do a binary search. Hence, the initial cost is the number of output
|
||||
** rows plus log2(table-size) times the number of binary searches.
|
||||
#ifdef SQLITE_ENABLE_STAT2
|
||||
/* If the constraint is of the form x=VALUE and histogram
|
||||
** data is available for column x, then it might be possible
|
||||
** to get a better estimate on the number of rows based on
|
||||
** VALUE and how common that value is according to the histogram.
|
||||
*/
|
||||
cost = nRow + nInMul*estLog(aiRowEst[0]);
|
||||
if( nRow>(double)1 && nEq==1 && pFirstTerm!=0 ){
|
||||
if( pFirstTerm->eOperator==WO_EQ ){
|
||||
whereEqualScanEst(pParse, pProbe, pFirstTerm->pExpr->pRight, &nRow);
|
||||
}else if( pFirstTerm->eOperator==WO_IN && bInEst==0 ){
|
||||
whereInScanEst(pParse, pProbe, pFirstTerm->pExpr->x.pList, &nRow);
|
||||
}
|
||||
}
|
||||
#endif /* SQLITE_ENABLE_STAT2 */
|
||||
|
||||
/* Adjust the number of rows and the cost downward to reflect rows
|
||||
** that are excluded by range constraints.
|
||||
*/
|
||||
nRow = (nRow * (double)estBound) / (double)100;
|
||||
cost = (cost * (double)estBound) / (double)100;
|
||||
if( nRow<1 ) nRow = 1;
|
||||
|
||||
/* Add in the estimated cost of sorting the result
|
||||
/* Assume constant cost to advance from one row to the next and
|
||||
** logarithmic cost to do a binary search. Hence, the initial cost
|
||||
** is the number of output rows plus log2(table-size) times the
|
||||
** number of binary searches.
|
||||
**
|
||||
** Because fan-out on tables is so much higher than the fan-out on
|
||||
** indices (because table btrees contain only integer keys in non-leaf
|
||||
** nodes) we weight the cost of a table binary search as 1/10th the
|
||||
** cost of an index binary search.
|
||||
*/
|
||||
if( pIdx ){
|
||||
if( bLookup ){
|
||||
/* For an index lookup followed by a table lookup:
|
||||
** nInMul index searches to find the start of each index range
|
||||
** + nRow steps through the index
|
||||
** + nRow table searches to lookup the table entry using the rowid
|
||||
*/
|
||||
nSearch = nInMul + nRow/10;
|
||||
}else{
|
||||
/* For a covering index:
|
||||
** nInMul binary searches to find the initial entry
|
||||
** + nRow steps through the index
|
||||
*/
|
||||
nSearch = nInMul;
|
||||
}
|
||||
}else{
|
||||
/* For a rowid primary key lookup:
|
||||
** nInMult binary searches to find the initial entry scaled by 1/10th
|
||||
** + nRow steps through the table
|
||||
*/
|
||||
nSearch = nInMul/10;
|
||||
}
|
||||
cost = nRow + nSearch*estLog(aiRowEst[0]);
|
||||
|
||||
/* Add in the estimated cost of sorting the result. This cost is expanded
|
||||
** by a fudge factor of 3.0 to account for the fact that a sorting step
|
||||
** involves a write and is thus more expensive than a lookup step.
|
||||
*/
|
||||
if( bSort ){
|
||||
cost += cost*estLog(cost);
|
||||
cost += nRow*estLog(nRow)*(double)3;
|
||||
}
|
||||
|
||||
/* If all information can be taken directly from the index, we avoid
|
||||
** doing table lookups. This reduces the cost by half. (Not really -
|
||||
** this needs to be fixed.)
|
||||
*/
|
||||
if( pIdx && bLookup==0 ){
|
||||
cost /= (double)2;
|
||||
}
|
||||
/**** Cost of using this index has now been computed ****/
|
||||
|
||||
/* If there are additional constraints on this table that cannot
|
||||
@ -2768,15 +3019,19 @@ static void bestBtreeIndex(
|
||||
}
|
||||
}else if( pTerm->eOperator & (WO_LT|WO_LE|WO_GT|WO_GE) ){
|
||||
if( nSkipRange ){
|
||||
/* Ignore the first nBound range constraints since the index
|
||||
/* Ignore the first nSkipRange range constraints since the index
|
||||
** has already accounted for these */
|
||||
nSkipRange--;
|
||||
}else{
|
||||
/* Assume each additional range constraint reduces the result
|
||||
** set size by a factor of 3 */
|
||||
** set size by a factor of 3. Indexed range constraints reduce
|
||||
** the search space by a larger factor: 4. We make indexed range
|
||||
** more selective intentionally because of the subjective
|
||||
** observation that indexed range constraints really are more
|
||||
** selective in practice, on average. */
|
||||
nRow /= 3;
|
||||
}
|
||||
}else{
|
||||
}else if( pTerm->eOperator!=WO_NOOP ){
|
||||
/* Any other expression lowers the output row count by half */
|
||||
nRow /= 2;
|
||||
}
|
||||
@ -3614,7 +3869,9 @@ static Bitmask codeOneLoopStart(
|
||||
if( pRangeStart ){
|
||||
Expr *pRight = pRangeStart->pExpr->pRight;
|
||||
sqlite3ExprCode(pParse, pRight, regBase+nEq);
|
||||
sqlite3ExprCodeIsNullJump(v, pRight, regBase+nEq, addrNxt);
|
||||
if( (pRangeStart->wtFlags & TERM_VNULL)==0 ){
|
||||
sqlite3ExprCodeIsNullJump(v, pRight, regBase+nEq, addrNxt);
|
||||
}
|
||||
if( zStartAff ){
|
||||
if( sqlite3CompareAffinity(pRight, zStartAff[nEq])==SQLITE_AFF_NONE){
|
||||
/* Since the comparison is to be performed with no conversions
|
||||
@ -3653,7 +3910,9 @@ static Bitmask codeOneLoopStart(
|
||||
Expr *pRight = pRangeEnd->pExpr->pRight;
|
||||
sqlite3ExprCacheRemove(pParse, regBase+nEq, 1);
|
||||
sqlite3ExprCode(pParse, pRight, regBase+nEq);
|
||||
sqlite3ExprCodeIsNullJump(v, pRight, regBase+nEq, addrNxt);
|
||||
if( (pRangeEnd->wtFlags & TERM_VNULL)==0 ){
|
||||
sqlite3ExprCodeIsNullJump(v, pRight, regBase+nEq, addrNxt);
|
||||
}
|
||||
if( zEndAff ){
|
||||
if( sqlite3CompareAffinity(pRight, zEndAff[nEq])==SQLITE_AFF_NONE){
|
||||
/* Since the comparison is to be performed with no conversions
|
||||
|
@ -154,22 +154,22 @@ do_eqp_test 2.6 {
|
||||
do_eqp_test 2.7 {
|
||||
SELECT * FROM t1 WHERE x BETWEEN -400 AND -300 AND y BETWEEN 100 AND 300
|
||||
} {
|
||||
0 0 0 {SEARCH TABLE t1 USING INDEX t1_x (x>? AND x<?) (~25 rows)}
|
||||
0 0 0 {SEARCH TABLE t1 USING INDEX t1_x (x>? AND x<?) (~12 rows)}
|
||||
}
|
||||
do_eqp_test 2.8 {
|
||||
SELECT * FROM t1 WHERE x BETWEEN 100 AND 300 AND y BETWEEN -400 AND -300
|
||||
} {
|
||||
0 0 0 {SEARCH TABLE t1 USING INDEX t1_y (y>? AND y<?) (~25 rows)}
|
||||
0 0 0 {SEARCH TABLE t1 USING INDEX t1_y (y>? AND y<?) (~12 rows)}
|
||||
}
|
||||
do_eqp_test 2.9 {
|
||||
SELECT * FROM t1 WHERE x BETWEEN 500 AND 100 AND y BETWEEN 100 AND 300
|
||||
} {
|
||||
0 0 0 {SEARCH TABLE t1 USING INDEX t1_x (x>? AND x<?) (~25 rows)}
|
||||
0 0 0 {SEARCH TABLE t1 USING INDEX t1_x (x>? AND x<?) (~12 rows)}
|
||||
}
|
||||
do_eqp_test 2.10 {
|
||||
SELECT * FROM t1 WHERE x BETWEEN 100 AND 300 AND y BETWEEN 500 AND 100
|
||||
} {
|
||||
0 0 0 {SEARCH TABLE t1 USING INDEX t1_y (y>? AND y<?) (~25 rows)}
|
||||
0 0 0 {SEARCH TABLE t1 USING INDEX t1_y (y>? AND y<?) (~12 rows)}
|
||||
}
|
||||
|
||||
do_test analyze2-3.1 {
|
||||
@ -207,7 +207,7 @@ do_eqp_test 3.3 {
|
||||
do_eqp_test 3.4 {
|
||||
SELECT * FROM t1 WHERE x BETWEEN 100 AND 400 AND y BETWEEN 'a' AND 'h'
|
||||
} {
|
||||
0 0 0 {SEARCH TABLE t1 USING INDEX t1_x (x>? AND x<?) (~50 rows)}
|
||||
0 0 0 {SEARCH TABLE t1 USING INDEX t1_x (x>? AND x<?) (~100 rows)}
|
||||
}
|
||||
do_eqp_test 3.5 {
|
||||
SELECT * FROM t1 WHERE x<'a' AND y>'h'
|
||||
@ -242,10 +242,12 @@ do_test analyze2-4.1 {
|
||||
} {}
|
||||
do_test analyze2-4.2 {
|
||||
execsql {
|
||||
PRAGMA automatic_index=OFF;
|
||||
SELECT tbl,idx,group_concat(sample,' ')
|
||||
FROM sqlite_stat2
|
||||
WHERE idx = 't3a'
|
||||
GROUP BY tbl,idx
|
||||
GROUP BY tbl,idx;
|
||||
PRAGMA automatic_index=ON;
|
||||
}
|
||||
} {t3 t3a {AfA bEj CEj dEj EEj fEj GEj hEj IEj jEj}}
|
||||
do_test analyze2-4.3 {
|
||||
@ -408,7 +410,7 @@ do_test analyze2-6.2.1 {
|
||||
t5.a>1 AND t5.a<15 AND
|
||||
t6.a>1
|
||||
}
|
||||
} {0 0 0 {SEARCH TABLE t5 USING COVERING INDEX t5i (a>? AND a<?) (~110000 rows)} 0 1 1 {SEARCH TABLE t6 USING INTEGER PRIMARY KEY (rowid=?) (~1 rows)}}
|
||||
} {0 0 0 {SEARCH TABLE t5 USING COVERING INDEX t5i (a>? AND a<?) (~60000 rows)} 0 1 1 {SEARCH TABLE t6 USING INTEGER PRIMARY KEY (rowid=?) (~1 rows)}}
|
||||
do_test analyze2-6.2.2 {
|
||||
db cache flush
|
||||
execsql ANALYZE
|
||||
@ -416,14 +418,14 @@ do_test analyze2-6.2.2 {
|
||||
t5.a>1 AND t5.a<15 AND
|
||||
t6.a>1
|
||||
}
|
||||
} {0 0 1 {SEARCH TABLE t6 USING COVERING INDEX t6i (a>?) (~2 rows)} 0 1 0 {SEARCH TABLE t5 USING INTEGER PRIMARY KEY (rowid=?) (~1 rows)}}
|
||||
} {0 0 1 {SEARCH TABLE t6 USING COVERING INDEX t6i (a>?) (~1 rows)} 0 1 0 {SEARCH TABLE t5 USING INTEGER PRIMARY KEY (rowid=?) (~1 rows)}}
|
||||
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 0 1 {SEARCH TABLE t6 USING COVERING INDEX t6i (a>?) (~2 rows)} 0 1 0 {SEARCH TABLE t5 USING INTEGER PRIMARY KEY (rowid=?) (~1 rows)}}
|
||||
} {0 0 1 {SEARCH TABLE t6 USING COVERING INDEX t6i (a>?) (~1 rows)} 0 1 0 {SEARCH TABLE t5 USING INTEGER PRIMARY KEY (rowid=?) (~1 rows)}}
|
||||
do_test analyze2-6.2.4 {
|
||||
execsql {
|
||||
PRAGMA writable_schema = 1;
|
||||
@ -434,7 +436,7 @@ do_test analyze2-6.2.4 {
|
||||
t5.a>1 AND t5.a<15 AND
|
||||
t6.a>1
|
||||
}
|
||||
} {0 0 0 {SEARCH TABLE t5 USING COVERING INDEX t5i (a>? AND a<?) (~110000 rows)} 0 1 1 {SEARCH TABLE t6 USING INTEGER PRIMARY KEY (rowid=?) (~1 rows)}}
|
||||
} {0 0 0 {SEARCH TABLE t5 USING COVERING INDEX t5i (a>? AND a<?) (~60000 rows)} 0 1 1 {SEARCH TABLE t6 USING INTEGER PRIMARY KEY (rowid=?) (~1 rows)}}
|
||||
do_test analyze2-6.2.5 {
|
||||
execsql {
|
||||
PRAGMA writable_schema = 1;
|
||||
@ -445,7 +447,7 @@ do_test analyze2-6.2.5 {
|
||||
t5.a>1 AND t5.a<15 AND
|
||||
t6.a>1
|
||||
}
|
||||
} {0 0 0 {SEARCH TABLE t5 USING COVERING INDEX t5i (a>? AND a<?) (~110000 rows)} 0 1 1 {SEARCH TABLE t6 USING INTEGER PRIMARY KEY (rowid=?) (~1 rows)}}
|
||||
} {0 0 0 {SEARCH TABLE t5 USING COVERING INDEX t5i (a>? AND a<?) (~60000 rows)} 0 1 1 {SEARCH TABLE t6 USING INTEGER PRIMARY KEY (rowid=?) (~1 rows)}}
|
||||
do_test analyze2-6.2.6 {
|
||||
execsql {
|
||||
PRAGMA writable_schema = 1;
|
||||
@ -457,7 +459,7 @@ do_test analyze2-6.2.6 {
|
||||
t5.a>1 AND t5.a<15 AND
|
||||
t6.a>1
|
||||
}
|
||||
} {0 0 1 {SEARCH TABLE t6 USING COVERING INDEX t6i (a>?) (~2 rows)} 0 1 0 {SEARCH TABLE t5 USING INTEGER PRIMARY KEY (rowid=?) (~1 rows)}}
|
||||
} {0 0 1 {SEARCH TABLE t6 USING COVERING INDEX t6i (a>?) (~1 rows)} 0 1 0 {SEARCH TABLE t5 USING INTEGER PRIMARY KEY (rowid=?) (~1 rows)}}
|
||||
|
||||
#--------------------------------------------------------------------
|
||||
# These tests, analyze2-7.*, test that the sqlite_stat2 functionality
|
||||
@ -501,7 +503,7 @@ ifcapable shared_cache {
|
||||
t5.a>1 AND t5.a<15 AND
|
||||
t6.a>1
|
||||
} db1
|
||||
} {0 0 1 {SEARCH TABLE t6 USING COVERING INDEX t6i (a>?) (~2 rows)} 0 1 0 {SEARCH TABLE t5 USING INTEGER PRIMARY KEY (rowid=?) (~1 rows)}}
|
||||
} {0 0 1 {SEARCH TABLE t6 USING COVERING INDEX t6i (a>?) (~1 rows)} 0 1 0 {SEARCH TABLE t5 USING INTEGER PRIMARY KEY (rowid=?) (~1 rows)}}
|
||||
do_test analyze2-7.6 {
|
||||
incr_schema_cookie test.db
|
||||
execsql { SELECT * FROM sqlite_master } db2
|
||||
@ -509,7 +511,7 @@ ifcapable shared_cache {
|
||||
t5.a>1 AND t5.a<15 AND
|
||||
t6.a>1
|
||||
} db2
|
||||
} {0 0 1 {SEARCH TABLE t6 USING COVERING INDEX t6i (a>?) (~2 rows)} 0 1 0 {SEARCH TABLE t5 USING INTEGER PRIMARY KEY (rowid=?) (~1 rows)}}
|
||||
} {0 0 1 {SEARCH TABLE t6 USING COVERING INDEX t6i (a>?) (~1 rows)} 0 1 0 {SEARCH TABLE t5 USING INTEGER PRIMARY KEY (rowid=?) (~1 rows)}}
|
||||
do_test analyze2-7.7 {
|
||||
incr_schema_cookie test.db
|
||||
execsql { SELECT * FROM sqlite_master } db1
|
||||
@ -517,7 +519,7 @@ ifcapable shared_cache {
|
||||
t5.a>1 AND t5.a<15 AND
|
||||
t6.a>1
|
||||
} db1
|
||||
} {0 0 1 {SEARCH TABLE t6 USING COVERING INDEX t6i (a>?) (~2 rows)} 0 1 0 {SEARCH TABLE t5 USING INTEGER PRIMARY KEY (rowid=?) (~1 rows)}}
|
||||
} {0 0 1 {SEARCH TABLE t6 USING COVERING INDEX t6i (a>?) (~1 rows)} 0 1 0 {SEARCH TABLE t5 USING INTEGER PRIMARY KEY (rowid=?) (~1 rows)}}
|
||||
|
||||
do_test analyze2-7.8 {
|
||||
execsql { DELETE FROM sqlite_stat2 } db2
|
||||
@ -526,14 +528,14 @@ ifcapable shared_cache {
|
||||
t5.a>1 AND t5.a<15 AND
|
||||
t6.a>1
|
||||
} db1
|
||||
} {0 0 1 {SEARCH TABLE t6 USING COVERING INDEX t6i (a>?) (~2 rows)} 0 1 0 {SEARCH TABLE t5 USING INTEGER PRIMARY KEY (rowid=?) (~1 rows)}}
|
||||
} {0 0 1 {SEARCH TABLE t6 USING COVERING INDEX t6i (a>?) (~1 rows)} 0 1 0 {SEARCH TABLE t5 USING INTEGER PRIMARY KEY (rowid=?) (~1 rows)}}
|
||||
do_test analyze2-7.9 {
|
||||
execsql { SELECT * FROM sqlite_master } db2
|
||||
eqp { SELECT * FROM t5,t6 WHERE t5.rowid=t6.rowid AND
|
||||
t5.a>1 AND t5.a<15 AND
|
||||
t6.a>1
|
||||
} db2
|
||||
} {0 0 1 {SEARCH TABLE t6 USING COVERING INDEX t6i (a>?) (~2 rows)} 0 1 0 {SEARCH TABLE t5 USING INTEGER PRIMARY KEY (rowid=?) (~1 rows)}}
|
||||
} {0 0 1 {SEARCH TABLE t6 USING COVERING INDEX t6i (a>?) (~1 rows)} 0 1 0 {SEARCH TABLE t5 USING INTEGER PRIMARY KEY (rowid=?) (~1 rows)}}
|
||||
|
||||
do_test analyze2-7.10 {
|
||||
incr_schema_cookie test.db
|
||||
@ -542,7 +544,7 @@ ifcapable shared_cache {
|
||||
t5.a>1 AND t5.a<15 AND
|
||||
t6.a>1
|
||||
} db1
|
||||
} {0 0 0 {SEARCH TABLE t5 USING COVERING INDEX t5i (a>? AND a<?) (~2 rows)} 0 1 1 {SEARCH TABLE t6 USING INTEGER PRIMARY KEY (rowid=?) (~1 rows)}}
|
||||
} {0 0 0 {SEARCH TABLE t5 USING COVERING INDEX t5i (a>? AND a<?) (~1 rows)} 0 1 1 {SEARCH TABLE t6 USING INTEGER PRIMARY KEY (rowid=?) (~1 rows)}}
|
||||
|
||||
db1 close
|
||||
db2 close
|
||||
|
@ -248,7 +248,7 @@ do_test analyze3-2.1 {
|
||||
} {}
|
||||
do_eqp_test analyze3-2.2 {
|
||||
SELECT count(a) FROM t1 WHERE b LIKE 'a%'
|
||||
} {0 0 0 {SEARCH TABLE t1 USING INDEX i1 (b>? AND b<?) (~55000 rows)}}
|
||||
} {0 0 0 {SEARCH TABLE t1 USING INDEX i1 (b>? AND b<?) (~30000 rows)}}
|
||||
do_eqp_test analyze3-2.3 {
|
||||
SELECT count(a) FROM t1 WHERE b LIKE '%a'
|
||||
} {0 0 0 {SCAN TABLE t1 (~500000 rows)}}
|
||||
|
194
test/analyze5.test
Normal file
194
test/analyze5.test
Normal file
@ -0,0 +1,194 @@
|
||||
# 2011 January 19
|
||||
#
|
||||
# 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 file implements tests for SQLite library. The focus of the tests
|
||||
# in this file is the use of the sqlite_stat2 histogram data on tables
|
||||
# with many repeated values and only a few distinct values.
|
||||
#
|
||||
|
||||
set testdir [file dirname $argv0]
|
||||
source $testdir/tester.tcl
|
||||
|
||||
ifcapable !stat2 {
|
||||
finish_test
|
||||
return
|
||||
}
|
||||
|
||||
set testprefix analyze5
|
||||
|
||||
proc eqp {sql {db db}} {
|
||||
uplevel execsql [list "EXPLAIN QUERY PLAN $sql"] $db
|
||||
}
|
||||
|
||||
unset -nocomplain i t u v w x y z
|
||||
do_test analyze5-1.0 {
|
||||
db eval {CREATE TABLE t1(t,u,v TEXT COLLATE nocase,w,x,y,z)}
|
||||
for {set i 0} {$i < 1000} {incr i} {
|
||||
set y [expr {$i>=25 && $i<=50}]
|
||||
set z [expr {($i>=400) + ($i>=700) + ($i>=875)}]
|
||||
set x $z
|
||||
set w $z
|
||||
set t [expr {$z+0.5}]
|
||||
switch $z {
|
||||
0 {set u "alpha"; unset x}
|
||||
1 {set u "bravo"}
|
||||
2 {set u "charlie"}
|
||||
3 {set u "delta"; unset w}
|
||||
}
|
||||
if {$i%2} {set v $u} {set v [string toupper $u]}
|
||||
db eval {INSERT INTO t1 VALUES($t,$u,$v,$w,$x,$y,$z)}
|
||||
}
|
||||
db eval {
|
||||
CREATE INDEX t1t ON t1(t); -- 0.5, 1.5, 2.5, and 3.5
|
||||
CREATE INDEX t1u ON t1(u); -- text
|
||||
CREATE INDEX t1v ON t1(v); -- mixed case text
|
||||
CREATE INDEX t1w ON t1(w); -- integers 0, 1, 2 and a few NULLs
|
||||
CREATE INDEX t1x ON t1(x); -- integers 1, 2, 3 and many NULLs
|
||||
CREATE INDEX t1y ON t1(y); -- integers 0 and very few 1s
|
||||
CREATE INDEX t1z ON t1(z); -- integers 0, 1, 2, and 3
|
||||
ANALYZE;
|
||||
SELECT sample FROM sqlite_stat2 WHERE idx='t1u' ORDER BY sampleno;
|
||||
}
|
||||
} {alpha alpha alpha alpha bravo bravo bravo charlie charlie delta}
|
||||
do_test analyze5-1.1 {
|
||||
string tolower \
|
||||
[db eval {SELECT sample from sqlite_stat2 WHERE idx='t1v' ORDER BY sampleno}]
|
||||
} {alpha alpha alpha alpha bravo bravo bravo charlie charlie delta}
|
||||
do_test analyze5-1.2 {
|
||||
db eval {SELECT sample from sqlite_stat2 WHERE idx='t1w' ORDER BY sampleno}
|
||||
} {{} 0 0 0 0 1 1 1 2 2}
|
||||
do_test analyze5-1.3 {
|
||||
db eval {SELECT sample from sqlite_stat2 WHERE idx='t1x' ORDER BY sampleno}
|
||||
} {{} {} {} {} 1 1 1 2 2 3}
|
||||
do_test analyze5-1.4 {
|
||||
db eval {SELECT sample from sqlite_stat2 WHERE idx='t1y' ORDER BY sampleno}
|
||||
} {0 0 0 0 0 0 0 0 0 0}
|
||||
do_test analyze5-1.5 {
|
||||
db eval {SELECT sample from sqlite_stat2 WHERE idx='t1z' ORDER BY sampleno}
|
||||
} {0 0 0 0 1 1 1 2 2 3}
|
||||
do_test analyze5-1.6 {
|
||||
db eval {SELECT sample from sqlite_stat2 WHERE idx='t1t' ORDER BY sampleno}
|
||||
} {0.5 0.5 0.5 0.5 1.5 1.5 1.5 2.5 2.5 3.5}
|
||||
|
||||
|
||||
# Verify that range queries generate the correct row count estimates
|
||||
#
|
||||
foreach {testid where index rows} {
|
||||
1 {z>=0 AND z<=0} t1z 400
|
||||
2 {z>=1 AND z<=1} t1z 300
|
||||
3 {z>=2 AND z<=2} t1z 200
|
||||
4 {z>=3 AND z<=3} t1z 100
|
||||
5 {z>=4 AND z<=4} t1z 50
|
||||
6 {z>=-1 AND z<=-1} t1z 50
|
||||
7 {z>1 AND z<3} t1z 200
|
||||
8 {z>0 AND z<100} t1z 600
|
||||
9 {z>=1 AND z<100} t1z 600
|
||||
10 {z>1 AND z<100} t1z 300
|
||||
11 {z>=2 AND z<100} t1z 300
|
||||
12 {z>2 AND z<100} t1z 100
|
||||
13 {z>=3 AND z<100} t1z 100
|
||||
14 {z>3 AND z<100} t1z 50
|
||||
15 {z>=4 AND z<100} t1z 50
|
||||
16 {z>=-100 AND z<=-1} t1z 50
|
||||
17 {z>=-100 AND z<=0} t1z 400
|
||||
18 {z>=-100 AND z<0} t1z 50
|
||||
19 {z>=-100 AND z<=1} t1z 700
|
||||
20 {z>=-100 AND z<2} t1z 700
|
||||
21 {z>=-100 AND z<=2} {} 111
|
||||
22 {z>=-100 AND z<3} {} 111
|
||||
|
||||
31 {z>=0.0 AND z<=0.0} t1z 400
|
||||
32 {z>=1.0 AND z<=1.0} t1z 300
|
||||
33 {z>=2.0 AND z<=2.0} t1z 200
|
||||
34 {z>=3.0 AND z<=3.0} t1z 100
|
||||
35 {z>=4.0 AND z<=4.0} t1z 50
|
||||
36 {z>=-1.0 AND z<=-1.0} t1z 50
|
||||
37 {z>1.5 AND z<3.0} t1z 200
|
||||
38 {z>0.5 AND z<100} t1z 600
|
||||
39 {z>=1.0 AND z<100} t1z 600
|
||||
40 {z>1.5 AND z<100} t1z 300
|
||||
41 {z>=2.0 AND z<100} t1z 300
|
||||
42 {z>2.1 AND z<100} t1z 100
|
||||
43 {z>=3.0 AND z<100} t1z 100
|
||||
44 {z>3.2 AND z<100} t1z 50
|
||||
45 {z>=4.0 AND z<100} t1z 50
|
||||
46 {z>=-100 AND z<=-1.0} t1z 50
|
||||
47 {z>=-100 AND z<=0.0} t1z 400
|
||||
48 {z>=-100 AND z<0.0} t1z 50
|
||||
49 {z>=-100 AND z<=1.0} t1z 700
|
||||
50 {z>=-100 AND z<2.0} t1z 700
|
||||
51 {z>=-100 AND z<=2.0} {} 111
|
||||
52 {z>=-100 AND z<3.0} {} 111
|
||||
|
||||
101 {z=-1} t1z 50
|
||||
102 {z=0} t1z 400
|
||||
103 {z=1} t1z 300
|
||||
104 {z=2} t1z 200
|
||||
105 {z=3} t1z 100
|
||||
106 {z=4} t1z 50
|
||||
107 {z=-10.0} t1z 50
|
||||
108 {z=0.0} t1z 400
|
||||
109 {z=1.0} t1z 300
|
||||
110 {z=2.0} t1z 200
|
||||
111 {z=3.0} t1z 100
|
||||
112 {z=4.0} t1z 50
|
||||
113 {z=1.5} t1z 50
|
||||
114 {z=2.5} t1z 50
|
||||
|
||||
201 {z IN (-1)} t1z 50
|
||||
202 {z IN (0)} t1z 400
|
||||
203 {z IN (1)} t1z 300
|
||||
204 {z IN (2)} t1z 200
|
||||
205 {z IN (3)} t1z 100
|
||||
206 {z IN (4)} t1z 50
|
||||
207 {z IN (0.5)} t1z 50
|
||||
208 {z IN (0,1)} t1z 700
|
||||
209 {z IN (0,1,2)} {} 100
|
||||
210 {z IN (0,1,2,3)} {} 100
|
||||
211 {z IN (0,1,2,3,4,5)} {} 100
|
||||
212 {z IN (1,2)} t1z 500
|
||||
213 {z IN (2,3)} t1z 300
|
||||
214 {z=3 OR z=2} t1z 300
|
||||
215 {z IN (-1,3)} t1z 150
|
||||
216 {z=-1 OR z=3} t1z 150
|
||||
|
||||
300 {y=0} {} 100
|
||||
301 {y=1} t1y 50
|
||||
302 {y=0.1} t1y 50
|
||||
|
||||
} {
|
||||
# Verify that the expected index is used with the expected row count
|
||||
do_test analyze5-1.${testid}a {
|
||||
set x [lindex [eqp "SELECT * FROM t1 WHERE $where"] 3]
|
||||
set idx {}
|
||||
regexp {INDEX (t1.) } $x all idx
|
||||
regexp {~([0-9]+) rows} $x all nrow
|
||||
list $idx $nrow
|
||||
} [list $index $rows]
|
||||
|
||||
# Verify that the same result is achieved regardless of whether or not
|
||||
# the index is used
|
||||
do_test analyze5-1.${testid}b {
|
||||
set w2 [string map {y +y z +z} $where]
|
||||
set a1 [db eval "SELECT rowid FROM t1 NOT INDEXED WHERE $w2\
|
||||
ORDER BY +rowid"]
|
||||
set a2 [db eval "SELECT rowid FROM t1 WHERE $where ORDER BY +rowid"]
|
||||
if {$a1==$a2} {
|
||||
set res ok
|
||||
} else {
|
||||
set res "a1=\[$a1\] a2=\[$a2\]"
|
||||
}
|
||||
set res
|
||||
} {ok}
|
||||
}
|
||||
|
||||
|
||||
finish_test
|
@ -1379,7 +1379,7 @@ do_createtable_tests 4.10 {
|
||||
{0 0 0 {SCAN TABLE t2 USING INDEX sqlite_autoindex_t2_1 (~1000000 rows)}}
|
||||
|
||||
3 "EXPLAIN QUERY PLAN SELECT * FROM t2 WHERE b=10 AND c>10"
|
||||
{0 0 0 {SEARCH TABLE t2 USING INDEX sqlite_autoindex_t2_1 (b=? AND c>?) (~3 rows)}}
|
||||
{0 0 0 {SEARCH TABLE t2 USING INDEX sqlite_autoindex_t2_1 (b=? AND c>?) (~2 rows)}}
|
||||
}
|
||||
|
||||
# EVIDENCE-OF: R-45493-35653 A CHECK constraint may be attached to a
|
||||
|
@ -392,7 +392,7 @@ det 5.3.1 "SELECT a, b FROM t1 WHERE a=1" {
|
||||
# (~1000000 rows)
|
||||
do_execsql_test 5.4.0 {CREATE TABLE t2(c, d)}
|
||||
det 5.4.1 "SELECT t1.*, t2.* FROM t1, t2 WHERE t1.a=1 AND t1.b>2" {
|
||||
0 0 0 {SEARCH TABLE t1 USING COVERING INDEX i2 (a=? AND b>?) (~3 rows)}
|
||||
0 0 0 {SEARCH TABLE t1 USING COVERING INDEX i2 (a=? AND b>?) (~2 rows)}
|
||||
0 1 1 {SCAN TABLE t2 (~1000000 rows)}
|
||||
}
|
||||
|
||||
@ -401,7 +401,7 @@ det 5.4.1 "SELECT t1.*, t2.* FROM t1, t2 WHERE t1.a=1 AND t1.b>2" {
|
||||
# USING COVERING INDEX i2 (a=? AND b>?) (~3 rows) 0|1|0|SCAN TABLE t2
|
||||
# (~1000000 rows)
|
||||
det 5.5 "SELECT t1.*, t2.* FROM t2, t1 WHERE t1.a=1 AND t1.b>2" {
|
||||
0 0 1 {SEARCH TABLE t1 USING COVERING INDEX i2 (a=? AND b>?) (~3 rows)}
|
||||
0 0 1 {SEARCH TABLE t1 USING COVERING INDEX i2 (a=? AND b>?) (~2 rows)}
|
||||
0 1 0 {SCAN TABLE t2 (~1000000 rows)}
|
||||
}
|
||||
|
||||
|
@ -154,10 +154,10 @@ do_test indexedby-4.4 {
|
||||
do_execsql_test indexedby-5.1 {
|
||||
CREATE VIEW v2 AS SELECT * FROM t1 INDEXED BY i1 WHERE a > 5;
|
||||
EXPLAIN QUERY PLAN SELECT * FROM v2
|
||||
} {0 0 0 {SEARCH TABLE t1 USING INDEX i1 (a>?) (~330000 rows)}}
|
||||
} {0 0 0 {SEARCH TABLE t1 USING INDEX i1 (a>?) (~250000 rows)}}
|
||||
do_execsql_test indexedby-5.2 {
|
||||
EXPLAIN QUERY PLAN SELECT * FROM v2 WHERE b = 10
|
||||
} {0 0 0 {SEARCH TABLE t1 USING INDEX i1 (a>?) (~33000 rows)}}
|
||||
} {0 0 0 {SEARCH TABLE t1 USING INDEX i1 (a>?) (~25000 rows)}}
|
||||
do_test indexedby-5.3 {
|
||||
execsql { DROP INDEX i1 }
|
||||
catchsql { SELECT * FROM v2 }
|
||||
|
@ -707,32 +707,32 @@ ifcapable like_opt&&!icu {
|
||||
INSERT INTO t10 VALUES(45,45,45,45,45,45);
|
||||
}
|
||||
count {
|
||||
SELECT a FROM t10 WHERE b LIKE '12%' ORDER BY a;
|
||||
SELECT a FROM t10 WHERE b LIKE '12%' ORDER BY +a;
|
||||
}
|
||||
} {12 123 scan 5 like 6}
|
||||
do_test like-10.2 {
|
||||
count {
|
||||
SELECT a FROM t10 WHERE c LIKE '12%' ORDER BY a;
|
||||
SELECT a FROM t10 WHERE c LIKE '12%' ORDER BY +a;
|
||||
}
|
||||
} {12 123 scan 5 like 6}
|
||||
do_test like-10.3 {
|
||||
count {
|
||||
SELECT a FROM t10 WHERE d LIKE '12%' ORDER BY a;
|
||||
SELECT a FROM t10 WHERE d LIKE '12%' ORDER BY +a;
|
||||
}
|
||||
} {12 123 scan 5 like 6}
|
||||
do_test like-10.4 {
|
||||
count {
|
||||
SELECT a FROM t10 WHERE e LIKE '12%' ORDER BY a;
|
||||
SELECT a FROM t10 WHERE e LIKE '12%' ORDER BY +a;
|
||||
}
|
||||
} {12 123 scan 5 like 6}
|
||||
do_test like-10.5 {
|
||||
count {
|
||||
SELECT a FROM t10 WHERE f LIKE '12%' ORDER BY a;
|
||||
SELECT a FROM t10 WHERE f LIKE '12%' ORDER BY +a;
|
||||
}
|
||||
} {12 123 scan 3 like 0}
|
||||
do_test like-10.6 {
|
||||
count {
|
||||
SELECT a FROM t10 WHERE a LIKE '12%' ORDER BY a;
|
||||
SELECT a FROM t10 WHERE a LIKE '12%' ORDER BY +a;
|
||||
}
|
||||
} {12 123 scan 5 like 6}
|
||||
do_test like-10.10 {
|
||||
@ -748,32 +748,32 @@ ifcapable like_opt&&!icu {
|
||||
INSERT INTO t10b SELECT * FROM t10;
|
||||
}
|
||||
count {
|
||||
SELECT a FROM t10b WHERE b GLOB '12*' ORDER BY a;
|
||||
SELECT a FROM t10b WHERE b GLOB '12*' ORDER BY +a;
|
||||
}
|
||||
} {12 123 scan 5 like 6}
|
||||
do_test like-10.11 {
|
||||
count {
|
||||
SELECT a FROM t10b WHERE c GLOB '12*' ORDER BY a;
|
||||
SELECT a FROM t10b WHERE c GLOB '12*' ORDER BY +a;
|
||||
}
|
||||
} {12 123 scan 5 like 6}
|
||||
do_test like-10.12 {
|
||||
count {
|
||||
SELECT a FROM t10b WHERE d GLOB '12*' ORDER BY a;
|
||||
SELECT a FROM t10b WHERE d GLOB '12*' ORDER BY +a;
|
||||
}
|
||||
} {12 123 scan 5 like 6}
|
||||
do_test like-10.13 {
|
||||
count {
|
||||
SELECT a FROM t10b WHERE e GLOB '12*' ORDER BY a;
|
||||
SELECT a FROM t10b WHERE e GLOB '12*' ORDER BY +a;
|
||||
}
|
||||
} {12 123 scan 5 like 6}
|
||||
do_test like-10.14 {
|
||||
count {
|
||||
SELECT a FROM t10b WHERE f GLOB '12*' ORDER BY a;
|
||||
SELECT a FROM t10b WHERE f GLOB '12*' ORDER BY +a;
|
||||
}
|
||||
} {12 123 scan 3 like 0}
|
||||
do_test like-10.15 {
|
||||
count {
|
||||
SELECT a FROM t10b WHERE a GLOB '12*' ORDER BY a;
|
||||
SELECT a FROM t10b WHERE a GLOB '12*' ORDER BY +a;
|
||||
}
|
||||
} {12 123 scan 5 like 6}
|
||||
}
|
||||
@ -819,7 +819,7 @@ do_test like-11.3 {
|
||||
queryplan {
|
||||
PRAGMA case_sensitive_like=OFF;
|
||||
CREATE INDEX t11b ON t11(b);
|
||||
SELECT b FROM t11 WHERE b LIKE 'abc%' ORDER BY a;
|
||||
SELECT b FROM t11 WHERE b LIKE 'abc%' ORDER BY +a;
|
||||
}
|
||||
} {abc abcd ABC ABCD sort {} t11b}
|
||||
do_test like-11.4 {
|
||||
@ -833,37 +833,37 @@ do_test like-11.5 {
|
||||
PRAGMA case_sensitive_like=OFF;
|
||||
DROP INDEX t11b;
|
||||
CREATE INDEX t11bnc ON t11(b COLLATE nocase);
|
||||
SELECT b FROM t11 WHERE b LIKE 'abc%' ORDER BY a;
|
||||
SELECT b FROM t11 WHERE b LIKE 'abc%' ORDER BY +a;
|
||||
}
|
||||
} {abc abcd ABC ABCD sort {} t11bnc}
|
||||
do_test like-11.6 {
|
||||
queryplan {
|
||||
CREATE INDEX t11bb ON t11(b COLLATE binary);
|
||||
SELECT b FROM t11 WHERE b LIKE 'abc%' ORDER BY a;
|
||||
SELECT b FROM t11 WHERE b LIKE 'abc%' ORDER BY +a;
|
||||
}
|
||||
} {abc abcd ABC ABCD sort {} t11bnc}
|
||||
do_test like-11.7 {
|
||||
queryplan {
|
||||
PRAGMA case_sensitive_like=ON;
|
||||
SELECT b FROM t11 WHERE b LIKE 'abc%' ORDER BY a;
|
||||
SELECT b FROM t11 WHERE b LIKE 'abc%' ORDER BY +a;
|
||||
}
|
||||
} {abc abcd sort {} t11bb}
|
||||
do_test like-11.8 {
|
||||
queryplan {
|
||||
PRAGMA case_sensitive_like=OFF;
|
||||
SELECT b FROM t11 WHERE b GLOB 'abc*' ORDER BY a;
|
||||
SELECT b FROM t11 WHERE b GLOB 'abc*' ORDER BY +a;
|
||||
}
|
||||
} {abc abcd sort {} t11bb}
|
||||
do_test like-11.9 {
|
||||
queryplan {
|
||||
CREATE INDEX t11cnc ON t11(c COLLATE nocase);
|
||||
CREATE INDEX t11cb ON t11(c COLLATE binary);
|
||||
SELECT c FROM t11 WHERE c LIKE 'abc%' ORDER BY a;
|
||||
SELECT c FROM t11 WHERE c LIKE 'abc%' ORDER BY +a;
|
||||
}
|
||||
} {abc abcd ABC ABCD sort {} t11cnc}
|
||||
do_test like-11.10 {
|
||||
queryplan {
|
||||
SELECT c FROM t11 WHERE c GLOB 'abc*' ORDER BY a;
|
||||
SELECT c FROM t11 WHERE c GLOB 'abc*' ORDER BY +a;
|
||||
}
|
||||
} {abc abcd sort {} t11cb}
|
||||
|
||||
|
@ -52,6 +52,7 @@ do_test minmax3-1.0 {
|
||||
INSERT INTO t1 VALUES('2', 'V', 'five');
|
||||
INSERT INTO t1 VALUES('3', 'VI', 'six');
|
||||
COMMIT;
|
||||
PRAGMA automatic_index=OFF;
|
||||
}
|
||||
} {}
|
||||
do_test minmax3-1.1.1 {
|
||||
|
@ -225,14 +225,14 @@ do_execsql_test where3-3.0 {
|
||||
ANALYZE;
|
||||
explain query plan SELECT * FROM t302, t301 WHERE t302.x=5 AND t301.a=t302.y;
|
||||
} {
|
||||
0 0 0 {SCAN TABLE t302 (~0 rows)}
|
||||
0 0 0 {SCAN TABLE t302 (~1 rows)}
|
||||
0 1 1 {SEARCH TABLE t301 USING INTEGER PRIMARY KEY (rowid=?) (~1 rows)}
|
||||
}
|
||||
do_execsql_test where3-3.1 {
|
||||
explain query plan
|
||||
SELECT * FROM t301, t302 WHERE t302.x=5 AND t301.a=t302.y;
|
||||
} {
|
||||
0 0 1 {SCAN TABLE t302 (~0 rows)}
|
||||
0 0 1 {SCAN TABLE t302 (~1 rows)}
|
||||
0 1 0 {SEARCH TABLE t301 USING INTEGER PRIMARY KEY (rowid=?) (~1 rows)}
|
||||
}
|
||||
|
||||
|
@ -472,7 +472,7 @@ ifcapable explain {
|
||||
do_execsql_test where9-5.3 {
|
||||
EXPLAIN QUERY PLAN SELECT a FROM t1 WHERE b>1000 AND (c>=31031 OR d IS NULL)
|
||||
} {
|
||||
0 0 0 {SEARCH TABLE t1 USING INDEX t1b (b>?) (~165000 rows)}
|
||||
0 0 0 {SEARCH TABLE t1 USING INDEX t1b (b>?) (~125000 rows)}
|
||||
}
|
||||
}
|
||||
|
||||
|
Loading…
Reference in New Issue
Block a user