Optimize IN operators in the WHERE clause of queries using virtual tables.

FossilOrigin-Name: 3d65c70343196b8f69c5293e7703839846fade85
This commit is contained in:
drh 2012-12-14 17:54:38 +00:00
commit 6d42097622
4 changed files with 149 additions and 67 deletions

View File

@ -1,5 +1,5 @@
C Generalize\sthe\smin/max\soptimization\sso\sthat\sif\san\sappropriate\sindex\sexists,\nthe\sindex\sit\scan\sbe\sused\sby\sany\saggregate\squery\sthat\scontains\sonly\sa\ssingle\nmax()\sor\smin()\sand\sdoes\snot\scontain\sa\sGROUP\sBY\sclause.
D 2012-12-13T18:57:31.980
C Optimize\sIN\soperators\sin\sthe\sWHERE\sclause\sof\squeries\susing\svirtual\stables.
D 2012-12-14T17:54:38.979
F Makefile.arm-wince-mingw32ce-gcc d6df77f1f48d690bd73162294bbba7f59507c72f
F Makefile.in 690d441a758cbffd13e814dc2724a721a6ebd400
F Makefile.linux-gcc 91d710bdc4998cb015f39edf3cb314ec4f4d7e23
@ -250,7 +250,7 @@ F src/vtab.c b05e5f1f4902461ba9f5fc49bb7eb7c3a0741a83
F src/wal.c f5c7b5027d0ed0e9bc9afeb4a3a8dfea762ec7d2
F src/wal.h 29c197540b19044e6cd73487017e5e47a1d3dac6
F src/walker.c 3d75ba73de15e0f8cd0737643badbeb0e002f07b
F src/where.c 53b991af50dab230b319b098bcb90fc7cd82da47
F src/where.c 7bdfde434b14ff88cc52ae41ac235ee1acb6b1e1
F test/8_3_names.test 631ea964a3edb091cf73c3b540f6bcfdb36ce823
F test/aggerror.test a867e273ef9e3d7919f03ef4f0e8c0d2767944f2
F test/aggnested.test 45c0201e28045ad38a530b5a144b73cd4aa2cfd6
@ -918,7 +918,7 @@ F test/vacuum4.test d3f8ecff345f166911568f397d2432c16d2867d9
F test/varint.test ab7b110089a08b9926ed7390e7e97bdefeb74102
F test/veryquick.test 7701bb609fe8bf6535514e8b849a309e8f00573b
F test/view.test b182a67ec43f490b156b5a710827a341be83dd17
F test/vtab1.test 36c9935e4be3b6350b31b6b697561b6fc3ab349a
F test/vtab1.test 4403f987860ebddef1ce2de6db7216421035339d
F test/vtab2.test 7bcffc050da5c68f4f312e49e443063e2d391c0d
F test/vtab3.test baad99fd27217f5d6db10660522e0b7192446de1
F test/vtab4.test 942f8b8280b3ea8a41dae20e7822d065ca1cb275
@ -1025,7 +1025,7 @@ F tool/vdbe-compress.tcl f12c884766bd14277f4fcedcae07078011717381
F tool/warnings-clang.sh f6aa929dc20ef1f856af04a730772f59283631d4
F tool/warnings.sh fbc018d67fd7395f440c28f33ef0f94420226381
F tool/win/sqlite.vsix 97894c2790eda7b5bce3cc79cb2a8ec2fde9b3ac
P 8bcf5f51d8a6ea47ba4eb8de001d7a30e0a5f2c3 7280e14cd8f55896451847b432171e8750a07c81
R dd1fb1ab301b504c23fc61d7da06adfc
P 52e755943f87354febe214e5dc3b423a1e38ba80 d2fb7619b063b329b6d7ba9a16a7290e5d868f23
R fea13d1ea2e8500bc200a6665b5fa212
U drh
Z c76dfaa5ec5d18c5fce102d2fd745bf3
Z 55c2c2e92a55016f5394cb88b53de07c

View File

@ -1 +1 @@
52e755943f87354febe214e5dc3b423a1e38ba80
3d65c70343196b8f69c5293e7703839846fade85

View File

@ -253,7 +253,7 @@ struct WhereCost {
#define WHERE_COLUMN_NULL 0x00080000 /* x IS NULL */
#define WHERE_INDEXED 0x000f0000 /* Anything that uses an index */
#define WHERE_NOT_FULLSCAN 0x100f3000 /* Does not do a full table scan */
#define WHERE_IN_ABLE 0x000f1000 /* Able to support an IN operator */
#define WHERE_IN_ABLE 0x080f1000 /* Able to support an IN operator */
#define WHERE_TOP_LIMIT 0x00100000 /* x<EXPR or x<=EXPR constraint */
#define WHERE_BTM_LIMIT 0x00200000 /* x>EXPR or x>=EXPR constraint */
#define WHERE_BOTH_LIMIT 0x00300000 /* Both x>EXPR and x<EXPR */
@ -2056,7 +2056,7 @@ static sqlite3_index_info *allocateIndexInfo(WhereBestIdx *p){
assert( (pTerm->eOperator&(pTerm->eOperator-1))==0 );
testcase( pTerm->eOperator==WO_IN );
testcase( pTerm->eOperator==WO_ISNULL );
if( pTerm->eOperator & (WO_IN|WO_ISNULL) ) continue;
if( pTerm->eOperator & (WO_ISNULL) ) continue;
if( pTerm->wtFlags & TERM_VNULL ) continue;
nTerm++;
}
@ -2104,15 +2104,18 @@ static sqlite3_index_info *allocateIndexInfo(WhereBestIdx *p){
pUsage;
for(i=j=0, pTerm=pWC->a; i<pWC->nTerm; i++, pTerm++){
u8 op;
if( pTerm->leftCursor != pSrc->iCursor ) continue;
assert( (pTerm->eOperator&(pTerm->eOperator-1))==0 );
testcase( pTerm->eOperator==WO_IN );
testcase( pTerm->eOperator==WO_ISNULL );
if( pTerm->eOperator & (WO_IN|WO_ISNULL) ) continue;
if( pTerm->eOperator & (WO_ISNULL) ) continue;
if( pTerm->wtFlags & TERM_VNULL ) continue;
pIdxCons[j].iColumn = pTerm->u.leftColumn;
pIdxCons[j].iTermOffset = i;
pIdxCons[j].op = (u8)pTerm->eOperator;
op = (u8)pTerm->eOperator;
if( op==WO_IN ) op = WO_EQ;
pIdxCons[j].op = op;
/* The direct assignment in the previous line is possible only because
** the WO_ and SQLITE_INDEX_CONSTRAINT_ codes are identical. The
** following asserts verify this fact. */
@ -2122,7 +2125,7 @@ static sqlite3_index_info *allocateIndexInfo(WhereBestIdx *p){
assert( WO_GT==SQLITE_INDEX_CONSTRAINT_GT );
assert( WO_GE==SQLITE_INDEX_CONSTRAINT_GE );
assert( WO_MATCH==SQLITE_INDEX_CONSTRAINT_MATCH );
assert( pTerm->eOperator & (WO_EQ|WO_LT|WO_LE|WO_GT|WO_GE|WO_MATCH) );
assert( pTerm->eOperator & (WO_IN|WO_EQ|WO_LT|WO_LE|WO_GT|WO_GE|WO_MATCH) );
j++;
}
for(i=0; i<nOrderBy; i++){
@ -2208,6 +2211,7 @@ static void bestVirtualIndex(WhereBestIdx *p){
WhereTerm *pTerm;
int i, j;
int nOrderBy;
int bAllowIN; /* Allow IN optimizations */
double rCost;
/* Make sure wsFlags is initialized to some sane value. Otherwise, if the
@ -2242,59 +2246,87 @@ static void bestVirtualIndex(WhereBestIdx *p){
assert( pTab->azModuleArg && pTab->azModuleArg[0] );
assert( sqlite3GetVTable(pParse->db, pTab) );
/* Set the aConstraint[].usable fields and initialize all
** output variables to zero.
**
** aConstraint[].usable is true for constraints where the right-hand
** side contains only references to tables to the left of the current
** table. In other words, if the constraint is of the form:
**
** column = expr
**
** and we are evaluating a join, then the constraint on column is
** only valid if all tables referenced in expr occur to the left
** of the table containing column.
**
** The aConstraints[] array contains entries for all constraints
** on the current table. That way we only have to compute it once
** even though we might try to pick the best index multiple times.
** For each attempt at picking an index, the order of tables in the
** join might be different so we have to recompute the usable flag
** each time.
/* Try once or twice. On the first attempt, allow IN optimizations.
** If an IN optimization is accepted by the virtual table xBestIndex
** method, but the pInfo->aConstrainUsage.omit flag is not set, then
** the query will not work because it might allow duplicate rows in
** output. In that case, run the xBestIndex method a second time
** without the IN constraints. Usually this loop only runs once.
** The loop will exit using a "break" statement.
*/
pIdxCons = *(struct sqlite3_index_constraint**)&pIdxInfo->aConstraint;
pUsage = pIdxInfo->aConstraintUsage;
for(i=0; i<pIdxInfo->nConstraint; i++, pIdxCons++){
j = pIdxCons->iTermOffset;
pTerm = &pWC->a[j];
pIdxCons->usable = (pTerm->prereqRight&p->notReady) ? 0 : 1;
}
memset(pUsage, 0, sizeof(pUsage[0])*pIdxInfo->nConstraint);
if( pIdxInfo->needToFreeIdxStr ){
sqlite3_free(pIdxInfo->idxStr);
}
pIdxInfo->idxStr = 0;
pIdxInfo->idxNum = 0;
pIdxInfo->needToFreeIdxStr = 0;
pIdxInfo->orderByConsumed = 0;
/* ((double)2) In case of SQLITE_OMIT_FLOATING_POINT... */
pIdxInfo->estimatedCost = SQLITE_BIG_DBL / ((double)2);
nOrderBy = pIdxInfo->nOrderBy;
if( !p->pOrderBy ){
pIdxInfo->nOrderBy = 0;
}
for(bAllowIN=1; 1; bAllowIN--){
assert( bAllowIN==0 || bAllowIN==1 );
if( vtabBestIndex(pParse, pTab, pIdxInfo) ){
return;
}
pIdxCons = *(struct sqlite3_index_constraint**)&pIdxInfo->aConstraint;
for(i=0; i<pIdxInfo->nConstraint; i++){
if( pUsage[i].argvIndex>0 ){
p->cost.used |= pWC->a[pIdxCons[i].iTermOffset].prereqRight;
/* Set the aConstraint[].usable fields and initialize all
** output variables to zero.
**
** aConstraint[].usable is true for constraints where the right-hand
** side contains only references to tables to the left of the current
** table. In other words, if the constraint is of the form:
**
** column = expr
**
** and we are evaluating a join, then the constraint on column is
** only valid if all tables referenced in expr occur to the left
** of the table containing column.
**
** The aConstraints[] array contains entries for all constraints
** on the current table. That way we only have to compute it once
** even though we might try to pick the best index multiple times.
** For each attempt at picking an index, the order of tables in the
** join might be different so we have to recompute the usable flag
** each time.
*/
pIdxCons = *(struct sqlite3_index_constraint**)&pIdxInfo->aConstraint;
pUsage = pIdxInfo->aConstraintUsage;
for(i=0; i<pIdxInfo->nConstraint; i++, pIdxCons++){
j = pIdxCons->iTermOffset;
pTerm = &pWC->a[j];
if( (pTerm->prereqRight&p->notReady)==0
&& (bAllowIN || pTerm->eOperator!=WO_IN)
){
pIdxCons->usable = 1;
}else{
pIdxCons->usable = 0;
}
}
memset(pUsage, 0, sizeof(pUsage[0])*pIdxInfo->nConstraint);
if( pIdxInfo->needToFreeIdxStr ){
sqlite3_free(pIdxInfo->idxStr);
}
pIdxInfo->idxStr = 0;
pIdxInfo->idxNum = 0;
pIdxInfo->needToFreeIdxStr = 0;
pIdxInfo->orderByConsumed = 0;
/* ((double)2) In case of SQLITE_OMIT_FLOATING_POINT... */
pIdxInfo->estimatedCost = SQLITE_BIG_DBL / ((double)2);
nOrderBy = pIdxInfo->nOrderBy;
if( !p->pOrderBy ){
pIdxInfo->nOrderBy = 0;
}
if( vtabBestIndex(pParse, pTab, pIdxInfo) ){
return;
}
pIdxCons = *(struct sqlite3_index_constraint**)&pIdxInfo->aConstraint;
for(i=0; i<pIdxInfo->nConstraint; i++, pIdxCons++){
if( pUsage[i].argvIndex>0 ){
j = pIdxCons->iTermOffset;
pTerm = &pWC->a[j];
p->cost.used |= pTerm->prereqRight;
if( pTerm->eOperator==WO_IN && pUsage[i].omit==0 ){
/* Do not attempt to use an IN constraint if the virtual table
** says that the equivalent EQ constraint cannot be safely omitted.
** If we do attempt to use such a constraint, some rows might be
** repeated in the output. */
break;
}
}
}
if( i>=pIdxInfo->nConstraint ) break;
}
/* If there is an ORDER BY clause, and the selected virtual table index
** does not satisfy it, increase the cost of the scan accordingly. This
** matches the processing for non-virtual tables in bestBtreeIndex().
@ -4063,6 +4095,7 @@ static Bitmask codeOneLoopStart(
** to access the data.
*/
int iReg; /* P3 Value for OP_VFilter */
int addrNotFound;
sqlite3_index_info *pVtabIdx = pLevel->plan.u.pVtabIdx;
int nConstraint = pVtabIdx->nConstraint;
struct sqlite3_index_constraint_usage *aUsage =
@ -4072,11 +4105,18 @@ static Bitmask codeOneLoopStart(
sqlite3ExprCachePush(pParse);
iReg = sqlite3GetTempRange(pParse, nConstraint+2);
addrNotFound = pLevel->addrBrk;
for(j=1; j<=nConstraint; j++){
for(k=0; k<nConstraint; k++){
if( aUsage[k].argvIndex==j ){
int iTerm = aConstraint[k].iTermOffset;
sqlite3ExprCode(pParse, pWC->a[iTerm].pExpr->pRight, iReg+j+1);
WhereTerm *pTerm = &pWC->a[aConstraint[k].iTermOffset];
int iTarget = iReg+j+1;
if( pTerm->eOperator & WO_IN ){
codeEqualityTerm(pParse, pTerm, pLevel, iTarget);
addrNotFound = pLevel->addrNxt;
}else{
sqlite3ExprCode(pParse, pTerm->pExpr->pRight, iTarget);
}
break;
}
}
@ -4084,7 +4124,7 @@ static Bitmask codeOneLoopStart(
}
sqlite3VdbeAddOp2(v, OP_Integer, pVtabIdx->idxNum, iReg);
sqlite3VdbeAddOp2(v, OP_Integer, j-1, iReg+1);
sqlite3VdbeAddOp4(v, OP_VFilter, iCur, addrBrk, iReg, pVtabIdx->idxStr,
sqlite3VdbeAddOp4(v, OP_VFilter, iCur, addrNotFound, iReg, pVtabIdx->idxStr,
pVtabIdx->needToFreeIdxStr ? P4_MPRINTF : P4_STATIC);
pVtabIdx->needToFreeIdxStr = 0;
for(j=0; j<nConstraint; j++){

View File

@ -1091,12 +1091,54 @@ do_test vtab1.13-3 {
} {15 {} 16}
do_test vtab1-14.001 {
execsql {SELECT rowid, * FROM echo_c WHERE +rowid IN (1,2,3)}
} {1 3 G H 2 {} 15 16 3 15 {} 16}
do_test vtab1-14.002 {
execsql {SELECT rowid, * FROM echo_c WHERE rowid IN (1,2,3)}
} {1 3 G H 2 {} 15 16 3 15 {} 16}
do_test vtab1-14.003 {
execsql {SELECT rowid, * FROM echo_c WHERE +rowid IN (0,1,5,2,'a',3,NULL)}
} {1 3 G H 2 {} 15 16 3 15 {} 16}
do_test vtab1-14.004 {
execsql {SELECT rowid, * FROM echo_c WHERE rowid IN (0,1,5,'a',2,3,NULL)}
} {1 3 G H 2 {} 15 16 3 15 {} 16}
do_test vtab1-14.005 {
execsql {SELECT rowid, * FROM echo_c WHERE rowid NOT IN (0,1,5,'a',2,3)}
} {}
do_test vtab1-14.006 {
execsql {SELECT rowid, * FROM echo_c WHERE rowid NOT IN (0,5,'a',2,3)}
} {1 3 G H}
do_test vtab1-14.007 {
execsql {SELECT rowid, * FROM echo_c WHERE +rowid NOT IN (0,5,'a',2,3,NULL)}
} {}
do_test vtab1-14.008 {
execsql {SELECT rowid, * FROM echo_c WHERE rowid NOT IN (0,5,'a',2,3,NULL)}
} {}
do_test vtab1-14.011 {
execsql {SELECT * FROM echo_c WHERE +a IN (1,3,8,'x',NULL,15,24)}
} {3 G H 15 {} 16}
do_test vtab1-14.012 {
execsql {SELECT * FROM echo_c WHERE a IN (1,3,8,'x',NULL,15,24)}
} {3 G H 15 {} 16}
do_test vtab1-14.013 {
execsql {SELECT * FROM echo_c WHERE a NOT IN (1,8,'x',15,24)}
} {3 G H}
do_test vtab1-14.014 {
execsql {SELECT * FROM echo_c WHERE a NOT IN (1,8,'x',NULL,15,24)}
} {}
do_test vtab1-14.015 {
execsql {SELECT * FROM echo_c WHERE +a NOT IN (1,8,'x',NULL,15,24)}
} {}
do_test vtab1-14.1 {
execsql { DELETE FROM c }
set echo_module ""
execsql { SELECT * FROM echo_c WHERE rowid IN (1, 2, 3) }
set echo_module
} [list xBestIndex {SELECT rowid, * FROM 'c'} xFilter {SELECT rowid, * FROM 'c'}]
} {/xBestIndex {SELECT rowid, . FROM 'c' WHERE rowid = .} xFilter {SELECT rowid, . FROM 'c' WHERE rowid = .} 1/}
do_test vtab1-14.2 {
set echo_module ""
@ -1114,7 +1156,7 @@ do_test vtab1-14.4 {
set echo_module ""
execsql { SELECT * FROM echo_c WHERE a IN (1, 2) }
set echo_module
} [list xBestIndex {SELECT rowid, * FROM 'c'} xFilter {SELECT rowid, * FROM 'c'}]
} {/xBestIndex {SELECT rowid, . FROM 'c' WHERE a = .} xFilter {SELECT rowid, . FROM 'c' WHERE a = .} 1/}
do_test vtab1-15.1 {
execsql {