Evaluate WHERE clause terms that reference only the index before evaluating

terms that require the table, and thereby avoid seeking the table row if
index terms are false.
This is called the "push-down" optimization in the MySQL world, we are told.

FossilOrigin-Name: d7bb79ed3a40419d143fbe35c310e51fe7b384a22f082a61ad788671d2d33ee0
This commit is contained in:
drh 2017-04-29 15:27:04 +00:00
commit bc43995f99
4 changed files with 117 additions and 41 deletions

View File

@ -1,5 +1,5 @@
C Add\snew\stest\sfile\scachespill.test. C Evaluate\sWHERE\sclause\sterms\sthat\sreference\sonly\sthe\sindex\sbefore\sevaluating\nterms\sthat\srequire\sthe\stable,\sand\sthereby\savoid\sseeking\sthe\stable\srow\sif\nindex\sterms\sare\sfalse.\nThis\sis\scalled\sthe\s"push-down"\soptimization\sin\sthe\sMySQL\sworld,\swe\sare\stold.
D 2017-04-26T17:21:33.779 D 2017-04-29T15:27:04.896
F Makefile.in 1cc758ce3374a32425e4d130c2fe7b026b20de5b8843243de75f087c0a2661fb F Makefile.in 1cc758ce3374a32425e4d130c2fe7b026b20de5b8843243de75f087c0a2661fb
F Makefile.linux-gcc 7bc79876b875010e8c8f9502eb935ca92aa3c434 F Makefile.linux-gcc 7bc79876b875010e8c8f9502eb935ca92aa3c434
F Makefile.msc 6a8c838220f7c00820e1fc0ac1bccaaa8e5676067e1dbfa1bafa7a4ffecf8ae6 F Makefile.msc 6a8c838220f7c00820e1fc0ac1bccaaa8e5676067e1dbfa1bafa7a4ffecf8ae6
@ -485,7 +485,7 @@ F src/wal.h 06b2a0b599cc0f53ea97f497cf8c6b758c999f71
F src/walker.c b71a992b413b3a022572eccf29ef4b4890223791 F src/walker.c b71a992b413b3a022572eccf29ef4b4890223791
F src/where.c c6352f15be5031907c68bcbde96cad1a6da20e9f4051d10168a59235de9a8566 F src/where.c c6352f15be5031907c68bcbde96cad1a6da20e9f4051d10168a59235de9a8566
F src/whereInt.h 2a4b634d63ce488b46d4b0da8f2eaa8f9aeab202bc25ef76f007de5e3fba1f20 F src/whereInt.h 2a4b634d63ce488b46d4b0da8f2eaa8f9aeab202bc25ef76f007de5e3fba1f20
F src/wherecode.c 943e32e9dccd0af802e0683ae11071c8bd808364e5908a5fb66758bd404c8681 F src/wherecode.c 8ad48867660519e262a401720845dc76934f86f558ec9606335fafcd7a2554f8
F src/whereexpr.c e913aaa7b73ffcce66abcea5f197e2c538d48b5df78d0b7bba8ff4d73cc2e745 F src/whereexpr.c e913aaa7b73ffcce66abcea5f197e2c538d48b5df78d0b7bba8ff4d73cc2e745
F test/8_3_names.test ebbb5cd36741350040fd28b432ceadf495be25b2 F test/8_3_names.test ebbb5cd36741350040fd28b432ceadf495be25b2
F test/affinity2.test a6d901b436328bd67a79b41bb0ac2663918fe3bd F test/affinity2.test a6d901b436328bd67a79b41bb0ac2663918fe3bd
@ -1043,6 +1043,7 @@ F test/printf.test b3ff34e73d59124140eaf89f7672e21bc2ca5fcc
F test/printf2.test 9e6db85f81c63f2367c34a9d7db384088bd374ad F test/printf2.test 9e6db85f81c63f2367c34a9d7db384088bd374ad
F test/progress.test ebab27f670bd0d4eb9d20d49cef96e68141d92fb F test/progress.test ebab27f670bd0d4eb9d20d49cef96e68141d92fb
F test/ptrchng.test ef1aa72d6cf35a2bbd0869a649b744e9d84977fc F test/ptrchng.test ef1aa72d6cf35a2bbd0869a649b744e9d84977fc
F test/pushdown.test a5d2e5e66cc94cfb0989a5dd23e77427dd6c4313019155ba9051f52dfc5326aa
F test/queryonly.test 5f653159e0f552f0552d43259890c1089391dcca F test/queryonly.test 5f653159e0f552f0552d43259890c1089391dcca
F test/quick.test 1681febc928d686362d50057c642f77a02c62e57 F test/quick.test 1681febc928d686362d50057c642f77a02c62e57
F test/quota-glob.test 32901e9eed6705d68ca3faee2a06b73b57cb3c26 F test/quota-glob.test 32901e9eed6705d68ca3faee2a06b73b57cb3c26
@ -1576,7 +1577,8 @@ F vsixtest/vsixtest.tcl 6a9a6ab600c25a91a7acc6293828957a386a8a93
F vsixtest/vsixtest.vcxproj.data 2ed517e100c66dc455b492e1a33350c1b20fbcdc F vsixtest/vsixtest.vcxproj.data 2ed517e100c66dc455b492e1a33350c1b20fbcdc
F vsixtest/vsixtest.vcxproj.filters 37e51ffedcdb064aad6ff33b6148725226cd608e F vsixtest/vsixtest.vcxproj.filters 37e51ffedcdb064aad6ff33b6148725226cd608e
F vsixtest/vsixtest_TemporaryKey.pfx e5b1b036facdb453873e7084e1cae9102ccc67a0 F vsixtest/vsixtest_TemporaryKey.pfx e5b1b036facdb453873e7084e1cae9102ccc67a0
P 63d9ca5c7392e1efe3330689fe750310a952287e843b3242178724e8561fae0e P 2d0b64316d66a362f5891ceb71a1fd8e4607732274b09b0a8472b97eef68ebc2 91dfb61a1a25763bb0b5c1e353a9d584bc6de3f6eb445f54202ffe7f6fee6e8d
R c4490df1c59aee5f8635e7285ee6a7e5 R d3fbd82e46a4092d676255e41f20df5b
U dan T +closed 91dfb61a1a25763bb0b5c1e353a9d584bc6de3f6eb445f54202ffe7f6fee6e8d
Z 2b0ae6051b3e0017c3cacc8dc5ffb6e4 U drh
Z d8af2da2fe4450264227719b4f172b61

View File

@ -1 +1 @@
2d0b64316d66a362f5891ceb71a1fd8e4607732274b09b0a8472b97eef68ebc2 d7bb79ed3a40419d143fbe35c310e51fe7b384a22f082a61ad788671d2d33ee0

View File

@ -1129,6 +1129,8 @@ Bitmask sqlite3WhereCodeOneLoopStart(
int addrCont; /* Jump here to continue with next cycle */ int addrCont; /* Jump here to continue with next cycle */
int iRowidReg = 0; /* Rowid is stored in this register, if not zero */ int iRowidReg = 0; /* Rowid is stored in this register, if not zero */
int iReleaseReg = 0; /* Temp register to free before returning */ int iReleaseReg = 0; /* Temp register to free before returning */
Index *pIdx = 0; /* Index used by loop (if any) */
int loopAgain; /* True if constraint generator loop should repeat */
pParse = pWInfo->pParse; pParse = pWInfo->pParse;
v = pParse->pVdbe; v = pParse->pVdbe;
@ -1454,7 +1456,6 @@ Bitmask sqlite3WhereCodeOneLoopStart(
int endEq; /* True if range end uses ==, >= or <= */ int endEq; /* True if range end uses ==, >= or <= */
int start_constraints; /* Start of range is constrained */ int start_constraints; /* Start of range is constrained */
int nConstraint; /* Number of constraint terms */ int nConstraint; /* Number of constraint terms */
Index *pIdx; /* The index we will be using */
int iIdxCur; /* The VDBE cursor for the index */ int iIdxCur; /* The VDBE cursor for the index */
int nExtraReg = 0; /* Number of extra registers needed */ int nExtraReg = 0; /* Number of extra registers needed */
int op; /* Instruction opcode */ int op; /* Instruction opcode */
@ -1705,6 +1706,7 @@ Bitmask sqlite3WhereCodeOneLoopStart(
}else{ }else{
assert( pLevel->p5==0 ); assert( pLevel->p5==0 );
} }
if( omitTable ) pIdx = 0;
}else }else
#ifndef SQLITE_OMIT_OR_OPTIMIZATION #ifndef SQLITE_OMIT_OR_OPTIMIZATION
@ -2022,43 +2024,56 @@ Bitmask sqlite3WhereCodeOneLoopStart(
/* Insert code to test every subexpression that can be completely /* Insert code to test every subexpression that can be completely
** computed using the current set of tables. ** computed using the current set of tables.
**
** This loop may run either once (pIdx==0) or twice (pIdx!=0). If
** it is run twice, then the first iteration codes those sub-expressions
** that can be computed using columns from pIdx only (without seeking
** the main table cursor).
*/ */
for(pTerm=pWC->a, j=pWC->nTerm; j>0; j--, pTerm++){ do{
Expr *pE; loopAgain = 0;
int skipLikeAddr = 0; for(pTerm=pWC->a, j=pWC->nTerm; j>0; j--, pTerm++){
testcase( pTerm->wtFlags & TERM_VIRTUAL ); Expr *pE;
testcase( pTerm->wtFlags & TERM_CODED ); int skipLikeAddr = 0;
if( pTerm->wtFlags & (TERM_VIRTUAL|TERM_CODED) ) continue; testcase( pTerm->wtFlags & TERM_VIRTUAL );
if( (pTerm->prereqAll & pLevel->notReady)!=0 ){ testcase( pTerm->wtFlags & TERM_CODED );
testcase( pWInfo->untestedTerms==0 if( pTerm->wtFlags & (TERM_VIRTUAL|TERM_CODED) ) continue;
&& (pWInfo->wctrlFlags & WHERE_OR_SUBCLAUSE)!=0 ); if( (pTerm->prereqAll & pLevel->notReady)!=0 ){
pWInfo->untestedTerms = 1; testcase( pWInfo->untestedTerms==0
continue; && (pWInfo->wctrlFlags & WHERE_OR_SUBCLAUSE)!=0 );
} pWInfo->untestedTerms = 1;
pE = pTerm->pExpr; continue;
assert( pE!=0 ); }
if( pLevel->iLeftJoin && !ExprHasProperty(pE, EP_FromJoin) ){ pE = pTerm->pExpr;
continue; assert( pE!=0 );
} if( pLevel->iLeftJoin && !ExprHasProperty(pE, EP_FromJoin) ){
if( pTerm->wtFlags & TERM_LIKECOND ){ continue;
/* If the TERM_LIKECOND flag is set, that means that the range search }
** is sufficient to guarantee that the LIKE operator is true, so we if( pIdx && !sqlite3ExprCoveredByIndex(pE, pLevel->iTabCur, pIdx) ){
** can skip the call to the like(A,B) function. But this only works loopAgain = 1;
** for strings. So do not skip the call to the function on the pass continue;
** that compares BLOBs. */ }
if( pTerm->wtFlags & TERM_LIKECOND ){
/* If the TERM_LIKECOND flag is set, that means that the range search
** is sufficient to guarantee that the LIKE operator is true, so we
** can skip the call to the like(A,B) function. But this only works
** for strings. So do not skip the call to the function on the pass
** that compares BLOBs. */
#ifdef SQLITE_LIKE_DOESNT_MATCH_BLOBS #ifdef SQLITE_LIKE_DOESNT_MATCH_BLOBS
continue; continue;
#else #else
u32 x = pLevel->iLikeRepCntr; u32 x = pLevel->iLikeRepCntr;
assert( x>0 ); assert( x>0 );
skipLikeAddr = sqlite3VdbeAddOp1(v, (x&1)? OP_IfNot : OP_If, (int)(x>>1)); skipLikeAddr = sqlite3VdbeAddOp1(v, (x&1)?OP_IfNot:OP_If, (int)(x>>1));
VdbeCoverage(v); VdbeCoverage(v);
#endif #endif
}
sqlite3ExprIfFalse(pParse, pE, addrCont, SQLITE_JUMPIFNULL);
if( skipLikeAddr ) sqlite3VdbeJumpHere(v, skipLikeAddr);
pTerm->wtFlags |= TERM_CODED;
} }
sqlite3ExprIfFalse(pParse, pE, addrCont, SQLITE_JUMPIFNULL); pIdx = 0;
if( skipLikeAddr ) sqlite3VdbeJumpHere(v, skipLikeAddr); }while( loopAgain );
pTerm->wtFlags |= TERM_CODED;
}
/* Insert code to test for implied constraints based on transitivity /* Insert code to test for implied constraints based on transitivity
** of the "==" operator. ** of the "==" operator.

59
test/pushdown.test Normal file
View File

@ -0,0 +1,59 @@
# 2017 April 29
#
# 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.
#
#***********************************************************************
set testdir [file dirname $argv0]
source $testdir/tester.tcl
set testprefix pushdown
do_execsql_test 1.0 {
CREATE TABLE t1(a, b, c);
INSERT INTO t1 VALUES(1, 'b1', 'c1');
INSERT INTO t1 VALUES(2, 'b2', 'c2');
INSERT INTO t1 VALUES(3, 'b3', 'c3');
INSERT INTO t1 VALUES(4, 'b4', 'c4');
CREATE INDEX i1 ON t1(a, c);
}
proc f {val} {
lappend ::L $val
return 0
}
db func f f
do_test 1.1 {
set L [list]
execsql { SELECT * FROM t1 WHERE a=2 AND f(b) AND f(c) }
set L
} {c2}
do_test 1.2 {
set L [list]
execsql { SELECT * FROM t1 WHERE a=3 AND f(c) AND f(b) }
set L
} {c3}
do_execsql_test 1.3 {
DROP INDEX i1;
CREATE INDEX i1 ON t1(a, b);
}
do_test 1.4 {
set L [list]
execsql { SELECT * FROM t1 WHERE a=2 AND f(b) AND f(c) }
set L
} {b2}
do_test 1.5 {
set L [list]
execsql { SELECT * FROM t1 WHERE a=3 AND f(c) AND f(b) }
set L
} {b3}
finish_test