From: drh Date: Thu, 28 Jul 2005 23:12:08 +0000 (+0000) Subject: The BETWEEN operator in a WHERE clause is now able to use indices. (CVS 2568) X-Git-Tag: version-3.6.10~3591 X-Git-Url: http://git.ipfire.org/?a=commitdiff_plain;h=ed378006933ebec04b6508a77edb3ce6fdb483d3;p=thirdparty%2Fsqlite.git The BETWEEN operator in a WHERE clause is now able to use indices. (CVS 2568) FossilOrigin-Name: cdf8c9584b945212e065e044df801c207aedb675 --- diff --git a/manifest b/manifest index b3cd0fb55d..3f07568a3e 100644 --- a/manifest +++ b/manifest @@ -1,5 +1,5 @@ -C Test\scases\sand\stuning\sof\sthe\snew\soptimizer\scode.\s(CVS\s2567) -D 2005-07-28T20:51:19 +C The\sBETWEEN\soperator\sin\sa\sWHERE\sclause\sis\snow\sable\sto\suse\sindices.\s(CVS\s2568) +D 2005-07-28T23:12:08 F Makefile.in 22ea9c0fe748f591712d8fe3c6d972c6c173a165 F Makefile.linux-gcc 06be33b2a9ad4f005a5f42b22c4a19dab3cbb5c7 F README 9c4e2d6706bdcc3efdd773ce752a8cdab4f90028 @@ -85,7 +85,7 @@ F src/vdbeapi.c 7f392f0792d1258c958083d7de9eae7c3530c9a6 F src/vdbeaux.c 3732a86566a6be4da4c606e9334baf3fd98667af F src/vdbefifo.c b8805850afe13b43f1de78d58088cb5d66f88e1e F src/vdbemem.c da8e8d6f29dd1323f782f000d7cd120027c9ff03 -F src/where.c 6c3de6ee253256d58ef07acb0f07458605477cd4 +F src/where.c c37799a796f490695211189608e1d5abeb01eea8 F tclinstaller.tcl 046e3624671962dc50f0481d7c25b38ef803eb42 F test/all.test 7f0988442ab811dfa41793b5b550f5828ce316f3 F test/alter.test 9d6837a3d946b73df692b7cef2a7644d2e2f6bc6 @@ -101,6 +101,7 @@ F test/autovacuum.test cf2719b17659f7a011202ad05905654cedf26023 F test/autovacuum_crash.test 05a63b8805b20cfba7ace82856ce4ccdda075a31 F test/autovacuum_ioerr.test 9cf27275ca47b72e188a47c53b61b6d583a01d24 F test/autovacuum_ioerr2.test 2f8a3fb31f833fd0ca86ad4ad98913c73e807572 +F test/between.test ca092fa28b665ca92172b182c6c360a92f7ca348 F test/bigfile.test d3744a8821ce9abb8697f2826a3e3d22b719e89f F test/bigrow.test f0aeb7573dcb8caaafea76454be3ade29b7fc747 F test/bind.test 3169339a9fb7aaa8244d0ed8651fe6b6796d809c @@ -225,7 +226,7 @@ F test/vacuum2.test 5d77e98c458bcdbeecc6327de5107179ba1aa095 F test/varint.test ab7b110089a08b9926ed7390e7e97bdefeb74102 F test/view.test 3c79232a2ee45918c62a0cf90411525899404a76 F test/where.test b6ab0f64adc5fbb4259f284b19da6cd9aeadc711 -F test/where2.test 6427619390385bf4fc357b3907b8733012964a92 +F test/where2.test 8696c35cd31b0a298de046f3fb6b684486a8b472 F tool/diffdb.c 7524b1b5df217c20cd0431f6789851a4e0cb191b F tool/lemon.c c88936c67f6411608db8fa4254d254f509fa40f6 F tool/lempar.c f0c30abcae762a7d1eb37cd88b2232ab8dd625fb @@ -288,7 +289,7 @@ F www/tclsqlite.tcl 425be741b8ae664f55cb1ef2371aab0a75109cf9 F www/vdbe.tcl 87a31ace769f20d3627a64fa1fade7fed47b90d0 F www/version3.tcl a99cf5f6d8bd4d5537584a2b342f0fb9fa601d8b F www/whentouse.tcl 528299b8316726dbcc5548e9aa0648c8b1bd055b -P a21212843359fb9fdbd60799ae50ad3566f4399a -R b3b6fd7089d32b94d5badcc51bbe97b5 +P 4b02703dec71aa78e5f8d8cab5b950966a4c6abc +R 5cec6ff48a1212708f6b9493ee851780 U drh -Z 603aecf655d7fb47a89068df78f35d0c +Z 6e3389c38b1260ced7a3d44c47196b06 diff --git a/manifest.uuid b/manifest.uuid index ad2b4e32c8..cc0b8b008b 100644 --- a/manifest.uuid +++ b/manifest.uuid @@ -1 +1 @@ -4b02703dec71aa78e5f8d8cab5b950966a4c6abc \ No newline at end of file +cdf8c9584b945212e065e044df801c207aedb675 \ No newline at end of file diff --git a/src/where.c b/src/where.c index 88f96f4235..e98d6542cb 100644 --- a/src/where.c +++ b/src/where.c @@ -16,7 +16,7 @@ ** so is applicable. Because this module is responsible for selecting ** indices, you might also think of this module as the "query optimizer". ** -** $Id: where.c,v 1.155 2005/07/28 20:51:19 drh Exp $ +** $Id: where.c,v 1.156 2005/07/28 23:12:08 drh Exp $ */ #include "sqliteInt.h" @@ -86,6 +86,7 @@ struct WhereTerm { i16 leftCursor; /* Cursor number of X in "X " */ i16 leftColumn; /* Column number of X in "X " */ u16 operator; /* A WO_xx value describing */ + u8 nPartner; /* Number of partners that must disable us */ WhereClause *pWC; /* The clause this term is part of */ Bitmask prereqRight; /* Bitmask of tables used by pRight */ Bitmask prereqAll; /* Bitmask of tables referenced by p */ @@ -477,6 +478,7 @@ static void exprAnalyze( pNew = whereClauseInsert(pTerm->pWC, pDup, TERM_VIRTUAL|TERM_DYNAMIC); if( pNew==0 ) return; pNew->iPartner = pTerm->idx; + pTerm->nPartner = 1; }else{ pDup = pExpr; pNew = pTerm; @@ -490,6 +492,30 @@ static void exprAnalyze( pNew->operator = operatorMask(pDup->op); } } + + /* If a term is the BETWEEN operator, create two new virtual terms + ** that define the range that the BETWEEN implements. + */ + else if( pExpr->op==TK_BETWEEN ){ + ExprList *pList = pExpr->pList; + int i; + static const u8 ops[] = {TK_GE, TK_LE}; + assert( pList!=0 ); + assert( pList->nExpr==2 ); + for(i=0; i<2; i++){ + Expr *pNewExpr; + WhereTerm *pNewTerm; + pNewExpr = sqlite3Expr(ops[i], sqlite3ExprDup(pExpr->pLeft), + sqlite3ExprDup(pList->a[i].pExpr), 0); + pNewTerm = whereClauseInsert(pTerm->pWC, pNewExpr, + TERM_VIRTUAL|TERM_DYNAMIC); + exprAnalyze(pSrc, pMaskSet, pNewTerm); + pNewTerm->iPartner = pTerm->idx; + } + pTerm->nPartner = 2; + } + + } @@ -890,7 +916,10 @@ static void disableTerm(WhereLevel *pLevel, WhereTerm *pTerm){ ){ pTerm->flags |= TERM_CODED; if( pTerm->iPartner>=0 ){ - disableTerm(pLevel, &pTerm->pWC->a[pTerm->iPartner]); + WhereTerm *pOther = &pTerm->pWC->a[pTerm->iPartner]; + if( (--pOther->nPartner)<=0 ){ + disableTerm(pLevel, pOther); + } } } } diff --git a/test/between.test b/test/between.test new file mode 100644 index 0000000000..7a262b360d --- /dev/null +++ b/test/between.test @@ -0,0 +1,106 @@ +# 2005 July 28 +# +# 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 the use of indices in WHERE clauses +# when the WHERE clause contains the BETWEEN operator. +# +# $Id: between.test,v 1.1 2005/07/28 23:12:08 drh Exp $ + +set testdir [file dirname $argv0] +source $testdir/tester.tcl + +# Build some test data +# +do_test between-1.0 { + execsql { + BEGIN; + CREATE TABLE t1(w int, x int, y int, z int); + } + for {set i 1} {$i<=100} {incr i} { + set w $i + set x [expr {int(log($i)/log(2))}] + set y [expr {$i*$i + 2*$i + 1}] + set z [expr {$x+$y}] + execsql {INSERT INTO t1 VALUES($::w,$::x,$::y,$::z)} + } + execsql { + CREATE UNIQUE INDEX i1w ON t1(w); + CREATE INDEX i1xy ON t1(x,y); + CREATE INDEX i1zyx ON t1(z,y,x); + COMMIT; + } +} {} + +# This procedure executes the SQL. Then it appends to the result the +# "sort" or "nosort" keyword depending on whether or not any sorting +# is done. Then it appends the ::sqlite_query_plan variable. +# +proc queryplan {sql} { + set ::sqlite_sort_count 0 + set data [execsql $sql] + if {$::sqlite_sort_count} {set x sort} {set x nosort} + lappend data $x + return [concat $data $::sqlite_query_plan] +} + +do_test between-1.1.1 { + queryplan { + SELECT * FROM t1 WHERE w BETWEEN 5 AND 6 ORDER BY +w + } +} {5 2 36 38 6 2 49 51 sort t1 i1w} +do_test between-1.1.2 { + queryplan { + SELECT * FROM t1 WHERE +w BETWEEN 5 AND 6 ORDER BY +w + } +} {5 2 36 38 6 2 49 51 sort t1 {}} +do_test between-1.2.1 { + queryplan { + SELECT * FROM t1 WHERE w BETWEEN 5 AND 65-y ORDER BY +w + } +} {5 2 36 38 6 2 49 51 sort t1 i1w} +do_test between-1.2.2 { + queryplan { + SELECT * FROM t1 WHERE +w BETWEEN 5 AND 65-y ORDER BY +w + } +} {5 2 36 38 6 2 49 51 sort t1 {}} +do_test between-1.3.1 { + queryplan { + SELECT * FROM t1 WHERE w BETWEEN 41-y AND 6 ORDER BY +w + } +} {5 2 36 38 6 2 49 51 sort t1 i1w} +do_test between-1.3.2 { + queryplan { + SELECT * FROM t1 WHERE +w BETWEEN 41-y AND 6 ORDER BY +w + } +} {5 2 36 38 6 2 49 51 sort t1 {}} +do_test between-1.4 { + queryplan { + SELECT * FROM t1 WHERE w BETWEEN 41-y AND 65-y ORDER BY +w + } +} {5 2 36 38 6 2 49 51 sort t1 {}} +do_test between-1.5.1 { + queryplan { + SELECT * FROM t1 WHERE 26 BETWEEN y AND z ORDER BY +w + } +} {4 2 25 27 sort t1 i1zyx} +do_test between-1.5.2 { + queryplan { + SELECT * FROM t1 WHERE 26 BETWEEN +y AND z ORDER BY +w + } +} {4 2 25 27 sort t1 i1zyx} +do_test between-1.5.3 { + queryplan { + SELECT * FROM t1 WHERE 26 BETWEEN y AND +z ORDER BY +w + } +} {4 2 25 27 sort t1 {}} + + +finish_test diff --git a/test/where2.test b/test/where2.test index ba5dcd2f58..f62963af79 100644 --- a/test/where2.test +++ b/test/where2.test @@ -12,7 +12,7 @@ # focus of this file is testing the use of indices in WHERE clauses # based on recent changes to the optimizer. # -# $Id: where2.test,v 1.1 2005/07/28 20:51:19 drh Exp $ +# $Id: where2.test,v 1.2 2005/07/28 23:12:08 drh Exp $ set testdir [file dirname $argv0] source $testdir/tester.tcl @@ -201,7 +201,6 @@ do_test where2-5.2 { } } {99 6 10000 10006 sort t1 i1w} - integrity_check {where2-99.0} finish_test