From: drh Date: Thu, 11 May 2006 13:26:25 +0000 (+0000) Subject: Correctly handle multi-column indices where multiple columns are constrained X-Git-Tag: version-3.6.10~2983 X-Git-Url: http://git.ipfire.org/?a=commitdiff_plain;h=ffe0f8901e20396fcfe49f317f3f1f2ab1dc94a9;p=thirdparty%2Fsqlite.git Correctly handle multi-column indices where multiple columns are constrained by IN operators with subqueries on the right-hand side. Ticket #1807. (CVS 3184) FossilOrigin-Name: b16541ba5e6a9514f9f317888117c68b6818f9cb --- diff --git a/manifest b/manifest index d8cb5b58f0..79fffd8ed2 100644 --- a/manifest +++ b/manifest @@ -1,5 +1,5 @@ -C Fix\scomments\son\sthe\simplementation\sof\sthe\sSUM()\sfunction.\s(CVS\s3183) -D 2006-05-11T13:25:39 +C Correctly\shandle\smulti-column\sindices\swhere\smultiple\scolumns\sare\sconstrained\nby\sIN\soperators\swith\ssubqueries\son\sthe\sright-hand\sside.\s\sTicket\s#1807.\s(CVS\s3184) +D 2006-05-11T13:26:26 F Makefile.in 5d8dff443383918b700e495de42ec65bc1c8865b F Makefile.linux-gcc 74ba0eadf88748a9ce3fd03d2a3ede2e6715baec F README 9c4e2d6706bdcc3efdd773ce752a8cdab4f90028 @@ -96,7 +96,7 @@ F src/vdbeapi.c 7dc662e7c905ce666bb506dced932e0307115cbf F src/vdbeaux.c 4002e6b19d7c9719cb81f9797316b9ad118e4370 F src/vdbefifo.c 9efb94c8c3f4c979ebd0028219483f88e57584f5 F src/vdbemem.c 5f0afe3b92bb2c037f8d5d697f7c151fa50783a3 -F src/where.c dc626f8c0fcff56ab7b08c9fb579d8ac33b0fbd9 +F src/where.c a8f0317d6e0b8b1681cb0dea51f08db97ea818e1 F tclinstaller.tcl 046e3624671962dc50f0481d7c25b38ef803eb42 F test/aggerror.test a867e273ef9e3d7919f03ef4f0e8c0d2767944f2 F test/all.test 5df90d015ca63fcef2a4b62c24f7316b66c4bfd4 @@ -281,7 +281,7 @@ F test/vacuum2.test 5aea8c88a65cb29f7d175296e7c819c6158d838c F test/varint.test ab7b110089a08b9926ed7390e7e97bdefeb74102 F test/view.test b0aeb933cc9dc5bb44d87f3859f3763d770f0153 F test/where.test ee7c9a6659b07e1ee61177f6e7ff71565ee2c9df -F test/where2.test fde821b9cb8e20d53ccd2e71482b063c5b1e222a +F test/where2.test a16476a5913e75cf65b38f2daa6157a6b7791394 F test/where3.test 6356013ce1c8ddc22a65c880dfff2b2c985634cb F tool/diffdb.c 7524b1b5df217c20cd0431f6789851a4e0cb191b F tool/lemon.c b0b881c172b5375444ef1c13d80ab01efec3605e @@ -355,7 +355,7 @@ F www/tclsqlite.tcl bb0d1357328a42b1993d78573e587c6dcbc964b9 F www/vdbe.tcl 87a31ace769f20d3627a64fa1fade7fed47b90d0 F www/version3.tcl 890248cf7b70e60c383b0e84d77d5132b3ead42b F www/whentouse.tcl 97e2b5cd296f7d8057e11f44427dea8a4c2db513 -P 364031d6e512b992a7147bbc8e046c20c0c5335a -R 9cfa66f5d989cfd0f2aaee034ce3a939 +P a8909f3e5fc67ac1ba7d1abd7fb0f4004fec5984 +R 3b9298194c78634fe2af414c3cfaec76 U drh -Z d937dfe62cc7b6890517312daa4fad61 +Z b60d85531a3794b0e00f9f1580fe1115 diff --git a/manifest.uuid b/manifest.uuid index 1fcf8c57fb..6f1a57b127 100644 --- a/manifest.uuid +++ b/manifest.uuid @@ -1 +1 @@ -a8909f3e5fc67ac1ba7d1abd7fb0f4004fec5984 \ No newline at end of file +b16541ba5e6a9514f9f317888117c68b6818f9cb \ No newline at end of file diff --git a/src/where.c b/src/where.c index 1c156c2180..73fc108b80 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.207 2006/04/21 09:38:37 drh Exp $ +** $Id: where.c,v 1.208 2006/05/11 13:26:26 drh Exp $ */ #include "sqliteInt.h" @@ -1034,7 +1034,7 @@ static double bestIndex( Expr *pExpr = pTerm->pExpr; flags |= WHERE_COLUMN_IN; if( pExpr->pSelect!=0 ){ - inMultiplier *= 100; + inMultiplier *= 25; }else if( pExpr->pList!=0 ){ inMultiplier *= pExpr->pList->nExpr + 1; } @@ -1224,17 +1224,16 @@ static void codeEqualityTerm( sqlite3CodeSubselect(pParse, pX); iTab = pX->iTable; - sqlite3VdbeAddOp(v, OP_Rewind, iTab, brk); + sqlite3VdbeAddOp(v, OP_Rewind, iTab, 0); VdbeComment((v, "# %.*s", pX->span.n, pX->span.z)); pLevel->nIn++; sqliteReallocOrFree((void**)&pLevel->aInLoop, - sizeof(pLevel->aInLoop[0])*3*pLevel->nIn); + sizeof(pLevel->aInLoop[0])*2*pLevel->nIn); aIn = pLevel->aInLoop; if( aIn ){ - aIn += pLevel->nIn*3 - 3; - aIn[0] = OP_Next; - aIn[1] = iTab; - aIn[2] = sqlite3VdbeAddOp(v, OP_Column, iTab, 0); + aIn += pLevel->nIn*2 - 2; + aIn[0] = iTab; + aIn[1] = sqlite3VdbeAddOp(v, OP_Column, iTab, 0); }else{ pLevel->nIn = 0; } @@ -2059,8 +2058,9 @@ void sqlite3WhereEnd(WhereInfo *pWInfo){ if( pLevel->nIn ){ int *a; int j; - for(j=pLevel->nIn, a=&pLevel->aInLoop[j*3-3]; j>0; j--, a-=3){ - sqlite3VdbeAddOp(v, a[0], a[1], a[2]); + for(j=pLevel->nIn, a=&pLevel->aInLoop[j*2-2]; j>0; j--, a-=2){ + sqlite3VdbeAddOp(v, OP_Next, a[0], a[1]); + sqlite3VdbeJumpHere(v, a[1]-1); } sqliteFree(pLevel->aInLoop); } diff --git a/test/where2.test b/test/where2.test index 04e057f5c9..b9b29f708e 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.8 2006/01/17 09:35:03 danielk1977 Exp $ +# $Id: where2.test,v 1.9 2006/05/11 13:26:26 drh Exp $ set testdir [file dirname $argv0] source $testdir/tester.tcl @@ -291,4 +291,164 @@ do_test where2-7.4 { } } {1 2 3 2 3 nosort} +# Ticket #1807. Using IN constrains on multiple columns of +# a multi-column index. +# +ifcapable subquery { + do_test where2-8.1 { + execsql { + SELECT * FROM t1 WHERE x IN (20,21) AND y IN (1,2) + } + } {} + do_test where2-8.2 { + execsql { + SELECT * FROM t1 WHERE x IN (1,2) AND y IN (-5,-6) + } + } {} + execsql {CREATE TABLE tx AS SELECT * FROM t1} + do_test where2-8.3 { + execsql { + SELECT w FROM t1 + WHERE x IN (SELECT x FROM tx WHERE rowid<0) + AND +y IN (SELECT y FROM tx WHERE rowid=1) + } + } {} + do_test where2-8.4 { + execsql { + SELECT w FROM t1 + WHERE x IN (SELECT x FROM tx WHERE rowid=1) + AND y IN (SELECT y FROM tx WHERE rowid<0) + } + } {} + #set sqlite_where_trace 1 + do_test where2-8.5 { + execsql { + CREATE INDEX tx_xyz ON tx(x, y, z, w); + SELECT w FROM tx + WHERE x IN (SELECT x FROM t1 WHERE w BETWEEN 10 AND 20) + AND y IN (SELECT y FROM t1 WHERE w BETWEEN 10 AND 20) + AND z IN (SELECT z FROM t1 WHERE w BETWEEN 12 AND 14) + } + } {12 13 14} + do_test where2-8.6 { + execsql { + SELECT w FROM tx + WHERE x IN (SELECT x FROM t1 WHERE w BETWEEN 10 AND 20) + AND y IN (SELECT y FROM t1 WHERE w BETWEEN 12 AND 14) + AND z IN (SELECT z FROM t1 WHERE w BETWEEN 10 AND 20) + } + } {12 13 14} + do_test where2-8.7 { + execsql { + SELECT w FROM tx + WHERE x IN (SELECT x FROM t1 WHERE w BETWEEN 12 AND 14) + AND y IN (SELECT y FROM t1 WHERE w BETWEEN 10 AND 20) + AND z IN (SELECT z FROM t1 WHERE w BETWEEN 10 AND 20) + } + } {10 11 12 13 14 15} + do_test where2-8.8 { + execsql { + SELECT w FROM tx + WHERE x IN (SELECT x FROM t1 WHERE w BETWEEN 10 AND 20) + AND y IN (SELECT y FROM t1 WHERE w BETWEEN 10 AND 20) + AND z IN (SELECT z FROM t1 WHERE w BETWEEN 10 AND 20) + } + } {10 11 12 13 14 15 16 17 18 19 20} + do_test where2-8.9 { + execsql { + SELECT w FROM tx + WHERE x IN (SELECT x FROM t1 WHERE w BETWEEN 10 AND 20) + AND y IN (SELECT y FROM t1 WHERE w BETWEEN 10 AND 20) + AND z IN (SELECT z FROM t1 WHERE w BETWEEN 2 AND 4) + } + } {} + do_test where2-8.10 { + execsql { + SELECT w FROM tx + WHERE x IN (SELECT x FROM t1 WHERE w BETWEEN 10 AND 20) + AND y IN (SELECT y FROM t1 WHERE w BETWEEN 2 AND 4) + AND z IN (SELECT z FROM t1 WHERE w BETWEEN 10 AND 20) + } + } {} + do_test where2-8.11 { + execsql { + SELECT w FROM tx + WHERE x IN (SELECT x FROM t1 WHERE w BETWEEN 2 AND 4) + AND y IN (SELECT y FROM t1 WHERE w BETWEEN 10 AND 20) + AND z IN (SELECT z FROM t1 WHERE w BETWEEN 10 AND 20) + } + } {} + do_test where2-8.12 { + execsql { + SELECT w FROM tx + WHERE x IN (SELECT x FROM t1 WHERE w BETWEEN 10 AND 20) + AND y IN (SELECT y FROM t1 WHERE w BETWEEN 10 AND 20) + AND z IN (SELECT z FROM t1 WHERE w BETWEEN -4 AND -2) + } + } {} + do_test where2-8.13 { + execsql { + SELECT w FROM tx + WHERE x IN (SELECT x FROM t1 WHERE w BETWEEN 10 AND 20) + AND y IN (SELECT y FROM t1 WHERE w BETWEEN -4 AND -2) + AND z IN (SELECT z FROM t1 WHERE w BETWEEN 10 AND 20) + } + } {} + do_test where2-8.14 { + execsql { + SELECT w FROM tx + WHERE x IN (SELECT x FROM t1 WHERE w BETWEEN -4 AND -2) + AND y IN (SELECT y FROM t1 WHERE w BETWEEN 10 AND 20) + AND z IN (SELECT z FROM t1 WHERE w BETWEEN 10 AND 20) + } + } {} + do_test where2-8.15 { + execsql { + SELECT w FROM tx + WHERE x IN (SELECT x FROM t1 WHERE w BETWEEN 10 AND 20) + AND y IN (SELECT y FROM t1 WHERE w BETWEEN 10 AND 20) + AND z IN (SELECT z FROM t1 WHERE w BETWEEN 200 AND 300) + } + } {} + do_test where2-8.16 { + execsql { + SELECT w FROM tx + WHERE x IN (SELECT x FROM t1 WHERE w BETWEEN 10 AND 20) + AND y IN (SELECT y FROM t1 WHERE w BETWEEN 200 AND 300) + AND z IN (SELECT z FROM t1 WHERE w BETWEEN 10 AND 20) + } + } {} + do_test where2-8.17 { + execsql { + SELECT w FROM tx + WHERE x IN (SELECT x FROM t1 WHERE w BETWEEN 200 AND 300) + AND y IN (SELECT y FROM t1 WHERE w BETWEEN 10 AND 20) + AND z IN (SELECT z FROM t1 WHERE w BETWEEN 10 AND 20) + } + } {} + do_test where2-8.18 { + execsql { + SELECT w FROM tx + WHERE x IN (SELECT x FROM t1 WHERE +w BETWEEN 10 AND 20) + AND y IN (SELECT y FROM t1 WHERE +w BETWEEN 10 AND 20) + AND z IN (SELECT z FROM t1 WHERE +w BETWEEN 200 AND 300) + } + } {} + do_test where2-8.19 { + execsql { + SELECT w FROM tx + WHERE x IN (SELECT x FROM t1 WHERE +w BETWEEN 10 AND 20) + AND y IN (SELECT y FROM t1 WHERE +w BETWEEN 200 AND 300) + AND z IN (SELECT z FROM t1 WHERE +w BETWEEN 10 AND 20) + } + } {} + do_test where2-8.20 { + execsql { + SELECT w FROM tx + WHERE x IN (SELECT x FROM t1 WHERE +w BETWEEN 200 AND 300) + AND y IN (SELECT y FROM t1 WHERE +w BETWEEN 10 AND 20) + AND z IN (SELECT z FROM t1 WHERE +w BETWEEN 10 AND 20) + } + } {} +} finish_test