Also make sure an index that is a proper subset of some other index has a

higher cost than that other index.  Add test cases.

FossilOrigin-Name: b7830d232b073a197aa1092e78cb24e88cb10fd3
This commit is contained in:
drh 2014-03-31 19:49:00 +00:00
parent 53cd10afcd
commit 3fb183d2f7
4 changed files with 185 additions and 37 deletions

View File

@ -1,5 +1,5 @@
C Make\ssure\sthat\san\sindex\sthat\scovers\sa\sproper\ssuperset\sof\sthe\sWHERE\sclause\nterms\sof\ssome\sother\sindex\shas\sa\slower\scost\sthan\sthe\sother\sindex.
D 2014-03-31T18:24:18.867
C Also\smake\ssure\san\sindex\sthat\sis\sa\sproper\ssubset\sof\ssome\sother\sindex\shas\sa\nhigher\scost\sthan\sthat\sother\sindex.\s\sAdd\stest\scases.
D 2014-03-31T19:49:00.374
F Makefile.arm-wince-mingw32ce-gcc d6df77f1f48d690bd73162294bbba7f59507c72f
F Makefile.in 2ef13430cd359f7b361bb863504e227b25cc7f81
F Makefile.linux-gcc 91d710bdc4998cb015f39edf3cb314ec4f4d7e23
@ -291,7 +291,7 @@ F src/vtab.c 21b932841e51ebd7d075e2d0ad1415dce8d2d5fd
F src/wal.c 76e7fc6de229bea8b30bb2539110f03a494dc3a8
F src/wal.h df01efe09c5cb8c8e391ff1715cca294f89668a4
F src/walker.c 11edb74d587bc87b33ca96a5173e3ec1b8389e45
F src/where.c 50ac3154473b5c8df15c7b8dbd19da385fa859e1
F src/where.c 182f16d91060418dfcc7401d24e43d8ec24e026c
F src/whereInt.h 2564055b440e44ebec8b47f237bbccae6719b7af
F test/8_3_names.test ebbb5cd36741350040fd28b432ceadf495be25b2
F test/aggerror.test a867e273ef9e3d7919f03ef4f0e8c0d2767944f2
@ -1093,6 +1093,7 @@ F test/whereD.test 6c2feb79ef1f68381b07f39017fe5f9b96da8d62
F test/whereE.test b3a055eef928c992b0a33198a7b8dc10eea5ad2f
F test/whereF.test 5b2ba0dbe8074aa13e416b37c753991f0a2492d7
F test/whereG.test eb3a46b3eaf38e25e3013433b2db8a25a866c215
F test/whereH.test e4b07f7a3c2f5d31195cd33710054c78667573b2
F test/wherelimit.test 5e9fd41e79bb2b2d588ed999d641d9c965619b31
F test/wild001.test bca33f499866f04c24510d74baf1e578d4e44b1c
F test/win32heap.test ea19770974795cff26e11575e12d422dbd16893c
@ -1159,7 +1160,7 @@ F tool/vdbe_profile.tcl 67746953071a9f8f2f668b73fe899074e2c6d8c1
F tool/warnings-clang.sh f6aa929dc20ef1f856af04a730772f59283631d4
F tool/warnings.sh d1a6de74685f360ab718efda6265994b99bbea01
F tool/win/sqlite.vsix 030f3eeaf2cb811a3692ab9c14d021a75ce41fff
P 8f869ca7a6eaa9ca7a08102290e6c606735f9090
R 76b8d8088ba83ec014dc8bf476fa6749
P ea8b0910040198751551b0b960e6b783913607df
R 176e1ff66c14893be5de17b3890f1972
U drh
Z ecebe13d1c9f7ea1da970c5f6118dc52
Z 3bf4657410567331f2f5534ba4eae60e

View File

@ -1 +1 @@
ea8b0910040198751551b0b960e6b783913607df
b7830d232b073a197aa1092e78cb24e88cb10fd3

View File

@ -3712,46 +3712,54 @@ static void whereInfoFree(sqlite3 *db, WhereInfo *pWInfo){
}
/*
** Compare every WhereLoop X on the list p against pTemplate. If:
** Return TRUE if the set of WHERE clause terms used by pA is a proper
** subset of the WHERE clause terms used by pB.
*/
static int whereLoopProperSubset(const WhereLoop *pA, const WhereLoop *pB){
int i, j;
if( pA->nLTerm>=pB->nLTerm ) return 0;
for(j=0, i=pA->nLTerm-1; i>=0 && j>=0; i--){
for(j=pB->nLTerm-1; j>=0; j--){
if( pB->aLTerm[j]==pA->aLTerm[i] ) break;
}
}
return j>=0;
}
/*
** Try to adjust the cost of WhereLoop pTemplate upwards or downwards so
** that:
**
** (1) both X and pTemplate refer to the same table, and
** (2) both X and pTemplate use a single index, and
** (3) pTemplate uses all the same WHERE clause terms as X plus
** at least one more term,
** (1) pTemplate costs less than any other WhereLoops that are a proper
** subset of pTemplate
**
** then make sure the cost pTemplate is less than the cost of X, adjusting
** the cost of pTemplate downward if necessary.
** (2) pTemplate costs more than any other WhereLoops for which pTemplate
** is a proper subset.
**
** Example: When computing the query plan for the SELECT below:
**
** CREATE TABLE t1(a,b,c,d);
** CREATE INDEX t1abc ON t1(a,b,c);
** CREATE INDEX t1bc ON t1(b,c);
** SELECT d FROM t1 WHERE a=? AND b=? AND c>=? ORDER BY c;
**
** Make sure the cost of using three three columns of index t1abc is less
** than the cost of using both columns of t1bc.
** To say "WhereLoop X is a proper subset of Y" means that X uses fewer
** WHERE clause terms than Y and that every WHERE clause term used by X is
** also used by Y.
*/
static void whereLoopAdjustCost(const WhereLoop *p, WhereLoop *pTemplate){
if( (pTemplate->wsFlags & WHERE_INDEXED)==0 ) return;
if( pTemplate->nLTerm==0 ) return;
for(; p; p=p->pNextLoop){
if( p->iTab==pTemplate->iTab
&& (p->wsFlags & WHERE_INDEXED)!=0
&& p->nLTerm<pTemplate->nLTerm
if( p->iTab!=pTemplate->iTab ) continue;
if( (p->wsFlags & WHERE_INDEXED)==0 ) continue;
if( p->nLTerm<pTemplate->nLTerm
&& (p->rRun<pTemplate->rRun || (p->rRun==pTemplate->rRun &&
p->nOut<=pTemplate->nOut))
&& whereLoopProperSubset(p, pTemplate)
){
int i, j;
for(j=0, i=p->nLTerm-1; i>=0 && j>=0; i--){
for(j=pTemplate->nLTerm-1; j>=0; j--){
if( pTemplate->aLTerm[j]==p->aLTerm[i] ) break;
}
}
if( j>=0 ){
pTemplate->rRun = p->rRun;
pTemplate->nOut = p->nOut - 1;
}
pTemplate->rRun = p->rRun;
pTemplate->nOut = p->nOut - 1;
}else
if( p->nLTerm>pTemplate->nLTerm
&& (p->rRun>pTemplate->rRun || (p->rRun==pTemplate->rRun &&
p->nOut>=pTemplate->nOut))
&& whereLoopProperSubset(pTemplate, p)
){
pTemplate->rRun = p->rRun;
pTemplate->nOut = p->nOut + 1;
}
}
}

139
test/whereH.test Normal file
View File

@ -0,0 +1,139 @@
# 2014-03-31
#
# 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.
#
#***********************************************************************
#
# Test cases for query planning decisions where one candidate index
# covers a proper superset of the WHERE clause terms of another
# candidate index.
#
set testdir [file dirname $argv0]
source $testdir/tester.tcl
do_execsql_test whereH-1.1 {
CREATE TABLE t1(a,b,c,d);
CREATE INDEX t1abc ON t1(a,b,c);
CREATE INDEX t1bc ON t1(b,c);
EXPLAIN QUERY PLAN
SELECT d FROM t1 WHERE a=? AND b=? AND c>=? ORDER BY c;
} {/INDEX t1abc /}
do_execsql_test whereH-1.2 {
EXPLAIN QUERY PLAN
SELECT d FROM t1 WHERE a=? AND b=? AND c>=? ORDER BY c;
} {~/TEMP B-TREE FOR ORDER BY/}
do_execsql_test whereH-2.1 {
DROP TABLE t1;
CREATE TABLE t1(a,b,c,d);
CREATE INDEX t1bc ON t1(b,c);
CREATE INDEX t1abc ON t1(a,b,c);
EXPLAIN QUERY PLAN
SELECT d FROM t1 WHERE a=? AND b=? AND c>=? ORDER BY c;
} {/INDEX t1abc /}
do_execsql_test whereH-2.2 {
EXPLAIN QUERY PLAN
SELECT d FROM t1 WHERE a=? AND b=? AND c>=? ORDER BY c;
} {~/TEMP B-TREE FOR ORDER BY/}
do_execsql_test whereH-3.1 {
DROP TABLE t1;
CREATE TABLE t1(a,b,c,d,e);
CREATE INDEX t1cd ON t1(c,d);
CREATE INDEX t1bcd ON t1(b,c,d);
CREATE INDEX t1abcd ON t1(a,b,c,d);
EXPLAIN QUERY PLAN
SELECT d FROM t1 WHERE a=? AND b=? AND c=? AND d>=? ORDER BY d;
} {/INDEX t1abcd /}
do_execsql_test whereH-3.2 {
EXPLAIN QUERY PLAN
SELECT d FROM t1 WHERE a=? AND b=? AND c=? AND d>=? ORDER BY d;
} {~/TEMP B-TREE FOR ORDER BY/}
do_execsql_test whereH-4.1 {
DROP TABLE t1;
CREATE TABLE t1(a,b,c,d,e);
CREATE INDEX t1cd ON t1(c,d);
CREATE INDEX t1abcd ON t1(a,b,c,d);
CREATE INDEX t1bcd ON t1(b,c,d);
EXPLAIN QUERY PLAN
SELECT d FROM t1 WHERE a=? AND b=? AND c=? AND d>=? ORDER BY d;
} {/INDEX t1abcd /}
do_execsql_test whereH-4.2 {
EXPLAIN QUERY PLAN
SELECT d FROM t1 WHERE a=? AND b=? AND c=? AND d>=? ORDER BY d;
} {~/TEMP B-TREE FOR ORDER BY/}
do_execsql_test whereH-5.1 {
DROP TABLE t1;
CREATE TABLE t1(a,b,c,d,e);
CREATE INDEX t1bcd ON t1(b,c,d);
CREATE INDEX t1cd ON t1(c,d);
CREATE INDEX t1abcd ON t1(a,b,c,d);
EXPLAIN QUERY PLAN
SELECT d FROM t1 WHERE a=? AND b=? AND c=? AND d>=? ORDER BY d;
} {/INDEX t1abcd /}
do_execsql_test whereH-5.2 {
EXPLAIN QUERY PLAN
SELECT d FROM t1 WHERE a=? AND b=? AND c=? AND d>=? ORDER BY d;
} {~/TEMP B-TREE FOR ORDER BY/}
do_execsql_test whereH-6.1 {
DROP TABLE t1;
CREATE TABLE t1(a,b,c,d,e);
CREATE INDEX t1bcd ON t1(b,c,d);
CREATE INDEX t1abcd ON t1(a,b,c,d);
CREATE INDEX t1cd ON t1(c,d);
EXPLAIN QUERY PLAN
SELECT d FROM t1 WHERE a=? AND b=? AND c=? AND d>=? ORDER BY d;
} {/INDEX t1abcd /}
do_execsql_test whereH-6.2 {
EXPLAIN QUERY PLAN
SELECT d FROM t1 WHERE a=? AND b=? AND c=? AND d>=? ORDER BY d;
} {~/TEMP B-TREE FOR ORDER BY/}
do_execsql_test whereH-7.1 {
DROP TABLE t1;
CREATE TABLE t1(a,b,c,d,e);
CREATE INDEX t1abcd ON t1(a,b,c,d);
CREATE INDEX t1bcd ON t1(b,c,d);
CREATE INDEX t1cd ON t1(c,d);
EXPLAIN QUERY PLAN
SELECT d FROM t1 WHERE a=? AND b=? AND c=? AND d>=? ORDER BY d;
} {/INDEX t1abcd /}
do_execsql_test whereH-7.2 {
EXPLAIN QUERY PLAN
SELECT d FROM t1 WHERE a=? AND b=? AND c=? AND d>=? ORDER BY d;
} {~/TEMP B-TREE FOR ORDER BY/}
do_execsql_test whereH-8.1 {
DROP TABLE t1;
CREATE TABLE t1(a,b,c,d,e);
CREATE INDEX t1abcd ON t1(a,b,c,d);
CREATE INDEX t1cd ON t1(c,d);
CREATE INDEX t1bcd ON t1(b,c,d);
EXPLAIN QUERY PLAN
SELECT d FROM t1 WHERE a=? AND b=? AND c=? AND d>=? ORDER BY d;
} {/INDEX t1abcd /}
do_execsql_test whereH-8.2 {
EXPLAIN QUERY PLAN
SELECT d FROM t1 WHERE a=? AND b=? AND c=? AND d>=? ORDER BY d;
} {~/TEMP B-TREE FOR ORDER BY/}
finish_test