When a WHERE clause contains disjuncts with the same operands, try to
combine them into a single operator. Example: (x=A OR x>A) becomes (x>=A). FossilOrigin-Name: 7a3097689d17625fb0dfc4372712f375f3bdb9a1
This commit is contained in:
parent
dfac7016a7
commit
8426636cdc
18
manifest
18
manifest
@ -1,5 +1,5 @@
|
||||
C Add\stests\sto\sensure\s"PRAGMA\sincremental_vacuum"\sand\s"PRAGMA\sauto_vacuum\s=\sincremental"\shandle\scorrupt\sdatabases\scorrectly.
|
||||
D 2015-03-13T15:44:36.085
|
||||
C When\sa\sWHERE\sclause\scontains\sdisjuncts\swith\sthe\ssame\soperands,\stry\sto\ncombine\sthem\sinto\sa\ssingle\soperator.\s\sExample:\s\s(x=A\sOR\sx>A)\sbecomes\n(x>=A).
|
||||
D 2015-03-16T12:13:31.967
|
||||
F Makefile.arm-wince-mingw32ce-gcc d6df77f1f48d690bd73162294bbba7f59507c72f
|
||||
F Makefile.in 88a3e6261286db378fdffa1124cad11b3c05f5bb
|
||||
F Makefile.linux-gcc 91d710bdc4998cb015f39edf3cb314ec4f4d7e23
|
||||
@ -307,7 +307,7 @@ F src/vxworks.h c18586c8edc1bddbc15c004fa16aeb1e1342b4fb
|
||||
F src/wal.c 39303f2c9db02a4e422cd8eb2c8760420c6a51fe
|
||||
F src/wal.h df01efe09c5cb8c8e391ff1715cca294f89668a4
|
||||
F src/walker.c c253b95b4ee44b21c406e2a1052636c31ea27804
|
||||
F src/where.c eb141b075776e9864d38f279333e2472a8653202
|
||||
F src/where.c b879a02e59c27f1447224fa2e79a7f2c7c345fd5
|
||||
F src/whereInt.h cbe4aa57326998d89e7698ca65bb7c28541d483c
|
||||
F test/8_3_names.test ebbb5cd36741350040fd28b432ceadf495be25b2
|
||||
F test/aggerror.test a867e273ef9e3d7919f03ef4f0e8c0d2767944f2
|
||||
@ -1175,6 +1175,7 @@ F test/whereG.test 69f5ec4b15760a8c860f80e2d55525669390aab3
|
||||
F test/whereH.test e4b07f7a3c2f5d31195cd33710054c78667573b2
|
||||
F test/whereI.test 1d89199697919d4930be05a71e7fe620f114e622
|
||||
F test/whereJ.test 55a3221706a7ab706293f17cc8f96da563bf0767
|
||||
F test/whereK.test 78fb50c74c9a91efc97a1daa39bcf7b8b68d8bff
|
||||
F test/wherelimit.test 5e9fd41e79bb2b2d588ed999d641d9c965619b31
|
||||
F test/wild001.test bca33f499866f04c24510d74baf1e578d4e44b1c
|
||||
F test/win32heap.test ea19770974795cff26e11575e12d422dbd16893c
|
||||
@ -1244,7 +1245,10 @@ F tool/vdbe_profile.tcl 67746953071a9f8f2f668b73fe899074e2c6d8c1
|
||||
F tool/warnings-clang.sh f6aa929dc20ef1f856af04a730772f59283631d4
|
||||
F tool/warnings.sh 0abfd78ceb09b7f7c27c688c8e3fe93268a13b32
|
||||
F tool/win/sqlite.vsix deb315d026cc8400325c5863eef847784a219a2f
|
||||
P 5aa522dcb9bfa18d49683f7cc889516984e2bcd2
|
||||
R a79445283a8ae7c7f85ae571d23bc239
|
||||
U dan
|
||||
Z d6c136b9ed1be16533c60706d0427e82
|
||||
P 1c2166cb2a387a0856f41b399c3648bf8c5fce73
|
||||
R 298b36c87aaf9227b23b4ea3e9cfdff1
|
||||
T *branch * combine-disjuncts
|
||||
T *sym-combine-disjuncts *
|
||||
T -sym-trunk *
|
||||
U drh
|
||||
Z 6e64b74890b4611813f6eecbfdcaf110
|
||||
|
@ -1 +1 @@
|
||||
1c2166cb2a387a0856f41b399c3648bf8c5fce73
|
||||
7a3097689d17625fb0dfc4372712f375f3bdb9a1
|
98
src/where.c
98
src/where.c
@ -770,6 +770,79 @@ static void markTermAsChild(WhereClause *pWC, int iChild, int iParent){
|
||||
pWC->a[iParent].nChild++;
|
||||
}
|
||||
|
||||
/*
|
||||
** Return the N-th AND-connected subterm of pTerm. Or if pTerm is not
|
||||
** a conjunction, then return just pTerm when N==0. If N is exceeds
|
||||
** the number of available subterms, return NULL.
|
||||
*/
|
||||
static WhereTerm *whereNthSubterm(WhereTerm *pTerm, int N){
|
||||
if( pTerm->eOperator!=WO_AND ){
|
||||
return N==0 ? pTerm : 0;
|
||||
}
|
||||
if( N<pTerm->u.pAndInfo->wc.nTerm ){
|
||||
return &pTerm->u.pAndInfo->wc.a[N];
|
||||
}
|
||||
return 0;
|
||||
}
|
||||
|
||||
/*
|
||||
** Subterms pOne and pTwo are contained within WHERE clause pWC. The
|
||||
** two subterms are in disjunction - they are OR-ed together.
|
||||
**
|
||||
** If these two terms are both of the form: "A op B" with the same
|
||||
** A and B values but different operators and if the operators are
|
||||
** compatible (if one is = and the other is <, for example) then
|
||||
** add a new virtual term to pWC that is the combination of the
|
||||
** two.
|
||||
**
|
||||
** Some examples:
|
||||
**
|
||||
** x<y OR x=y --> x<=y
|
||||
** x=y OR x=y --> x=y
|
||||
** x<=y OR x<y --> x<=y
|
||||
**
|
||||
** The following is NOT generated:
|
||||
**
|
||||
** x<y OR x>y --> x!=y
|
||||
*/
|
||||
static void whereCombineDisjuncts(
|
||||
SrcList *pSrc, /* the FROM clause */
|
||||
WhereClause *pWC, /* The complete WHERE clause */
|
||||
WhereTerm *pOne, /* First disjunct */
|
||||
WhereTerm *pTwo /* Second disjunct */
|
||||
){
|
||||
u16 eOp = pOne->eOperator | pTwo->eOperator;
|
||||
sqlite3 *db; /* Database connection (for malloc) */
|
||||
Expr *pNew; /* New virtual expression */
|
||||
int op; /* Operator for the combined expression */
|
||||
int idxNew; /* Index in pWC of the next virtual term */
|
||||
|
||||
if( (pOne->eOperator & (WO_EQ|WO_LT|WO_LE|WO_GT|WO_GE))==0 ) return;
|
||||
if( (pTwo->eOperator & (WO_EQ|WO_LT|WO_LE|WO_GT|WO_GE))==0 ) return;
|
||||
if( (eOp & (WO_EQ|WO_LT|WO_LE))!=eOp
|
||||
&& (eOp & (WO_EQ|WO_GT|WO_GE))!=eOp ) return;
|
||||
assert( pOne->pExpr->pLeft!=0 && pOne->pExpr->pRight!=0 );
|
||||
assert( pTwo->pExpr->pLeft!=0 && pTwo->pExpr->pRight!=0 );
|
||||
if( sqlite3ExprCompare(pOne->pExpr->pLeft, pTwo->pExpr->pLeft, -1) ) return;
|
||||
if( sqlite3ExprCompare(pOne->pExpr->pRight, pTwo->pExpr->pRight, -1) )return;
|
||||
/* If we reach this point, it means the two subterms can be combined */
|
||||
if( (eOp & (eOp-1))!=0 ){
|
||||
if( eOp & (WO_LT|WO_LE) ){
|
||||
eOp = WO_LE;
|
||||
}else{
|
||||
assert( eOp & (WO_GT|WO_GE) );
|
||||
eOp = WO_GE;
|
||||
}
|
||||
}
|
||||
db = pWC->pWInfo->pParse->db;
|
||||
pNew = sqlite3ExprDup(db, pOne->pExpr, 0);
|
||||
if( pNew==0 ) return;
|
||||
for(op=TK_EQ; eOp!=(WO_EQ<<(op-TK_EQ)); op++){ assert( op<TK_GE ); }
|
||||
pNew->op = op;
|
||||
idxNew = whereClauseInsert(pWC, pNew, TERM_VIRTUAL|TERM_DYNAMIC);
|
||||
exprAnalyze(pSrc, pWC, idxNew);
|
||||
}
|
||||
|
||||
#if !defined(SQLITE_OMIT_OR_OPTIMIZATION) && !defined(SQLITE_OMIT_SUBQUERY)
|
||||
/*
|
||||
** Analyze a term that consists of two or more OR-connected
|
||||
@ -794,6 +867,7 @@ static void markTermAsChild(WhereClause *pWC, int iChild, int iParent){
|
||||
** (C) t1.x=t2.y OR (t1.x=t2.z AND t1.y=15)
|
||||
** (D) x=expr1 OR (y>11 AND y<22 AND z LIKE '*hello*')
|
||||
** (E) (p.a=1 AND q.b=2 AND r.c=3) OR (p.x=4 AND q.y=5 AND r.z=6)
|
||||
** (F) x>A OR (x=A AND y>=B)
|
||||
**
|
||||
** CASE 1:
|
||||
**
|
||||
@ -810,6 +884,12 @@ static void markTermAsChild(WhereClause *pWC, int iChild, int iParent){
|
||||
**
|
||||
** CASE 2:
|
||||
**
|
||||
** If there is a two-way OR and one side has x>A and the other side
|
||||
** has x=A (for the same x and A) then add a new virtual term to the
|
||||
** WHERE clause of the form "x>=A".
|
||||
**
|
||||
** CASE 3:
|
||||
**
|
||||
** If all subterms are indexable by a single table T, then set
|
||||
**
|
||||
** WhereTerm.eOperator = WO_OR
|
||||
@ -936,12 +1016,26 @@ static void exprAnalyzeOrTerm(
|
||||
}
|
||||
|
||||
/*
|
||||
** Record the set of tables that satisfy case 2. The set might be
|
||||
** Record the set of tables that satisfy case 3. The set might be
|
||||
** empty.
|
||||
*/
|
||||
pOrInfo->indexable = indexable;
|
||||
pTerm->eOperator = indexable==0 ? 0 : WO_OR;
|
||||
|
||||
/* For a two-way OR, attempt to implementation case 2.
|
||||
*/
|
||||
if( indexable && pOrWc->nTerm==2 ){
|
||||
int iOne = 0;
|
||||
WhereTerm *pOne;
|
||||
while( (pOne = whereNthSubterm(&pOrWc->a[0],iOne++))!=0 ){
|
||||
int iTwo = 0;
|
||||
WhereTerm *pTwo;
|
||||
while( (pTwo = whereNthSubterm(&pOrWc->a[1],iTwo++))!=0 ){
|
||||
whereCombineDisjuncts(pSrc, pWC, pOne, pTwo);
|
||||
}
|
||||
}
|
||||
}
|
||||
|
||||
/*
|
||||
** chngToIN holds a set of tables that *might* satisfy case 1. But
|
||||
** we have to do some additional checking to see if case 1 really
|
||||
@ -1071,7 +1165,7 @@ static void exprAnalyzeOrTerm(
|
||||
}else{
|
||||
sqlite3ExprListDelete(db, pList);
|
||||
}
|
||||
pTerm->eOperator = WO_NOOP; /* case 1 trumps case 2 */
|
||||
pTerm->eOperator = WO_NOOP; /* case 1 trumps case 3 */
|
||||
}
|
||||
}
|
||||
}
|
||||
|
72
test/whereK.test
Normal file
72
test/whereK.test
Normal file
@ -0,0 +1,72 @@
|
||||
# 2015-03-16
|
||||
#
|
||||
# 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 regression tests for SQLite library. The
|
||||
# focus of this file is testing OR expressions where terms can be
|
||||
# factored from either side of the OR and combined into a single new
|
||||
# AND term that is beneficial to the search. Examples:
|
||||
#
|
||||
# (x>A OR x=A) --> ... AND (x>=A)
|
||||
# (x>A OR (x=A AND y>=B) --> ... AND (x>=A)
|
||||
#
|
||||
|
||||
|
||||
|
||||
set testdir [file dirname $argv0]
|
||||
source $testdir/tester.tcl
|
||||
set ::testprefix whereD
|
||||
|
||||
do_execsql_test 1.1 {
|
||||
CREATE TABLE t1(a,b,c);
|
||||
WITH RECURSIVE c(x) AS (VALUES(0) UNION ALL SELECT x+1 FROM c WHERE x<99)
|
||||
INSERT INTO t1(a,b,c) SELECT x, x/10, x%10 FROM c;
|
||||
CREATE INDEX t1bc ON t1(b,c);
|
||||
SELECT a FROM t1 WHERE b>9 OR b=9 ORDER BY +a;
|
||||
} {90 91 92 93 94 95 96 97 98 99}
|
||||
do_execsql_test 1.1eqp {
|
||||
EXPLAIN QUERY PLAN
|
||||
SELECT a FROM t1 WHERE b>9 OR b=9 ORDER BY +a;
|
||||
} {/SEARCH TABLE t1 USING INDEX t1bc/}
|
||||
|
||||
do_execsql_test 1.2 {
|
||||
SELECT a FROM t1 WHERE b>8 OR (b=8 AND c>7) ORDER BY +a;
|
||||
} {88 89 90 91 92 93 94 95 96 97 98 99}
|
||||
do_execsql_test 1.2eqp {
|
||||
EXPLAIN QUERY PLAN
|
||||
SELECT a FROM t1 WHERE b>8 OR (b=8 AND c>7) ORDER BY +a;
|
||||
} {/SEARCH TABLE t1 USING INDEX t1bc/}
|
||||
|
||||
do_execsql_test 1.3 {
|
||||
SELECT a FROM t1 WHERE (b=8 AND c>7) OR b>8 ORDER BY +a;
|
||||
} {88 89 90 91 92 93 94 95 96 97 98 99}
|
||||
do_execsql_test 1.3eqp {
|
||||
EXPLAIN QUERY PLAN
|
||||
SELECT a FROM t1 WHERE (b=8 AND c>7) OR b>8 ORDER BY +a;
|
||||
} {/SEARCH TABLE t1 USING INDEX t1bc/}
|
||||
|
||||
do_execsql_test 1.4 {
|
||||
SELECT a FROM t1 WHERE (b=8 AND c>7) OR 8<b ORDER BY +a;
|
||||
} {88 89 90 91 92 93 94 95 96 97 98 99}
|
||||
do_execsql_test 1.4eqp {
|
||||
EXPLAIN QUERY PLAN
|
||||
SELECT a FROM t1 WHERE (b=8 AND c>7) OR 8<b ORDER BY +a;
|
||||
} {/SEARCH TABLE t1 USING INDEX t1bc/}
|
||||
|
||||
do_execsql_test 1.5 {
|
||||
SELECT a FROM t1 WHERE (b=8 AND c>7) OR (b>8 AND c NOT IN (4,5,6))
|
||||
ORDER BY +a;
|
||||
} {88 89 90 91 92 93 97 98 99}
|
||||
do_execsql_test 1.5eqp {
|
||||
EXPLAIN QUERY PLAN
|
||||
SELECT a FROM t1 WHERE (b=8 AND c>7) OR (b>8 AND c NOT IN (4,5,6))
|
||||
ORDER BY +a;
|
||||
} {/SEARCH TABLE t1 USING INDEX t1bc/}
|
||||
|
||||
finish_test
|
Loading…
Reference in New Issue
Block a user