diff --git a/manifest b/manifest index 0da10ee6c4..953aa940c7 100644 --- a/manifest +++ b/manifest @@ -1,5 +1,5 @@ -C Allow\sconstraint\snames\son\sDEFAULT\svalues\sin\sa\stable\sdefinition.\nTicket\s#2109.\s(CVS\s3535) -D 2006-12-20T02:15:00 +C The\squery\soptimizer\sdoes\sa\sbetter\sjob\sof\soptimizing\sout\sORDER\sBY\sclauses\nthat\scontain\sthe\srowid\sor\swhich\suse\sindices\sthat\scontain\sthe\srowid.\nTicket\s#2116.\s(CVS\s3536) +D 2006-12-20T03:24:19 F Makefile.in 8e14898d41a53033ecb687d93c9cd5d109fb9ae3 F Makefile.linux-gcc 2d8574d1ba75f129aba2019f0b959db380a90935 F README 9c4e2d6706bdcc3efdd773ce752a8cdab4f90028 @@ -129,7 +129,7 @@ F src/vdbeaux.c 05cc6f0f82b86dfb4c356e06ab07ec8cc83a2eda F src/vdbefifo.c 9efb94c8c3f4c979ebd0028219483f88e57584f5 F src/vdbemem.c 26623176bf1c616aa478da958fac49502491a921 F src/vtab.c aa30e940058ea56a1b7a9a7019ec21d307316fb4 -F src/where.c b34cc2c7f753cdf76aa37a71e579c2e266e50958 +F src/where.c f55d4459a122457a135cf9ec859bf28777d9156f F tclinstaller.tcl 046e3624671962dc50f0481d7c25b38ef803eb42 F test/aggerror.test a867e273ef9e3d7919f03ef4f0e8c0d2767944f2 F test/all.test b62fcd122052efaff1b0979aefa2dd65cfc8ee52 @@ -348,7 +348,7 @@ F test/vtab6.test ec0036f29f8a803da9935206f2d9d1b6a8026392 F test/vtab7.test 5f9ef9fb84733e928d5d0267c821072561b198d5 F test/vtab9.test 87afba55339b0c255e9697fbfb5bfb6120505d9d F test/vtab_err.test c07f7665dd90bc757f80f05e7951d826eda9bc48 -F test/where.test ee7c9a6659b07e1ee61177f6e7ff71565ee2c9df +F test/where.test 8dcc1b1a6f17b6bad2dc6a9917eafe62d4ea57eb F test/where2.test 61d5b20d9bedc8788a773bbdc5b2ef887725928e F test/where3.test 0a30fe9808b0fa01c46d0fcf4fac0bf6cf75bb30 F tool/diffdb.c 7524b1b5df217c20cd0431f6789851a4e0cb191b @@ -423,7 +423,7 @@ F www/tclsqlite.tcl bb0d1357328a42b1993d78573e587c6dcbc964b9 F www/vdbe.tcl 87a31ace769f20d3627a64fa1fade7fed47b90d0 F www/version3.tcl 890248cf7b70e60c383b0e84d77d5132b3ead42b F www/whentouse.tcl 97e2b5cd296f7d8057e11f44427dea8a4c2db513 -P c3d118b40811b201e4a98b62549c5439d7d5098d -R ee31e902c9098dae721605bcf38ca561 +P 893d58c23da2a9b900a13eaa5202d94429862136 +R b71e90ccc82c8a1640aa72f2c870612e U drh -Z 6de8d7d606a906d10c3edc457d084a8d +Z 9fec3d60f3cf9eea1be494a067e0f511 diff --git a/manifest.uuid b/manifest.uuid index 2ad57094a0..89fb96bd75 100644 --- a/manifest.uuid +++ b/manifest.uuid @@ -1 +1 @@ -893d58c23da2a9b900a13eaa5202d94429862136 \ No newline at end of file +f245f5c2c2d337fe6458824beb7f9e721837765f \ No newline at end of file diff --git a/src/where.c b/src/where.c index 1d640cb26e..a0d2f81096 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.233 2006/12/16 16:25:16 drh Exp $ +** $Id: where.c,v 1.234 2006/12/20 03:24:19 drh Exp $ */ #include "sqliteInt.h" @@ -868,11 +868,19 @@ static int isSortingIndex( /* Match terms of the ORDER BY clause against columns of ** the index. + ** + ** Note that indices have pIdx->nColumn regular columns plus + ** one additional column containing the rowid. The rowid column + ** of the index is also allowed to match against the ORDER BY + ** clause. */ - for(i=j=0, pTerm=pOrderBy->a; jnColumn; i++){ + for(i=j=0, pTerm=pOrderBy->a; jnColumn; i++){ Expr *pExpr; /* The expression of the ORDER BY pTerm */ CollSeq *pColl; /* The collating sequence of pExpr */ int termSortOrder; /* Sort order for this term */ + int iColumn; /* The i-th column of the index. -1 for rowid */ + int iSortOrder; /* 1 for DESC, 0 for ASC on the i-th index term */ + const char *zColl; /* Name of the collating sequence for i-th index term */ pExpr = pTerm->pExpr; if( pExpr->op!=TK_COLUMN || pExpr->iTable!=base ){ @@ -881,9 +889,22 @@ static int isSortingIndex( return 0; } pColl = sqlite3ExprCollSeq(pParse, pExpr); - if( !pColl ) pColl = db->pDfltColl; - if( pExpr->iColumn!=pIdx->aiColumn[i] || - sqlite3StrICmp(pColl->zName, pIdx->azColl[i]) ){ + if( !pColl ){ + pColl = db->pDfltColl; + } + if( inColumn ){ + iColumn = pIdx->aiColumn[i]; + if( iColumn==pIdx->pTable->iPKey ){ + iColumn = -1; + } + iSortOrder = pIdx->aSortOrder[i]; + zColl = pIdx->azColl[i]; + }else{ + iColumn = -1; + iSortOrder = 0; + zColl = pColl->zName; + } + if( pExpr->iColumn!=iColumn || sqlite3StrICmp(pColl->zName, zColl) ){ /* Term j of the ORDER BY clause does not match column i of the index */ if( iaSortOrder!=0 ); assert( pTerm->sortOrder==0 || pTerm->sortOrder==1 ); - assert( pIdx->aSortOrder[i]==0 || pIdx->aSortOrder[i]==1 ); - termSortOrder = pIdx->aSortOrder[i] ^ pTerm->sortOrder; + assert( iSortOrder==0 || iSortOrder==1 ); + termSortOrder = iSortOrder ^ pTerm->sortOrder; if( i>nEqCol ){ if( termSortOrder!=sortOrder ){ /* Indices can only be used if all ORDER BY terms past the @@ -912,13 +933,25 @@ static int isSortingIndex( } j++; pTerm++; + if( iColumn<0 ){ + /* If the indexed column is the primary key and everything matches + ** so far, then we are assured that the index can be used to sort + ** because the primary key is unique and so none of the other columns + ** will make any difference + */ + j = nTerm; + } } - /* The index can be used for sorting if all terms of the ORDER BY clause - ** are covered. - */ + *pbRev = sortOrder!=0; if( j>=nTerm ){ - *pbRev = sortOrder!=0; + /* All terms of the ORDER BY clause are covered by this index so + ** this index can be used for sorting. */ + return 1; + } + if( j==pIdx->nColumn && pIdx->onError!=OE_None ){ + /* All terms of this index match some prefix of the ORDER BY clause + ** and this index is UNIQUE, so this index can be used for sorting. */ return 1; } return 0; @@ -939,8 +972,7 @@ static int sortableByRowid( assert( pOrderBy!=0 ); assert( pOrderBy->nExpr>0 ); p = pOrderBy->a[0].pExpr; - if( pOrderBy->nExpr==1 && p->op==TK_COLUMN && p->iTable==base - && p->iColumn==-1 ){ + if( p->op==TK_COLUMN && p->iTable==base && p->iColumn==-1 ){ *pbRev = pOrderBy->a[0].sortOrder; return 1; } diff --git a/test/where.test b/test/where.test index 83bcd0b8d6..8eeb3f81e6 100644 --- a/test/where.test +++ b/test/where.test @@ -11,7 +11,7 @@ # This file implements regression tests for SQLite library. The # focus of this file is testing the use of indices in WHERE clases. # -# $Id: where.test,v 1.38 2005/11/14 22:29:06 drh Exp $ +# $Id: where.test,v 1.39 2006/12/20 03:24:19 drh Exp $ set testdir [file dirname $argv0] source $testdir/tester.tcl @@ -589,22 +589,22 @@ do_test where-6.21 { cksort { SELECT y FROM t1 ORDER BY rowid, y LIMIT 3; } -} {4 9 16 sort} +} {4 9 16 nosort} do_test where-6.22 { cksort { SELECT y FROM t1 ORDER BY rowid, y DESC LIMIT 3; } -} {4 9 16 sort} +} {4 9 16 nosort} do_test where-6.23 { cksort { SELECT y FROM t1 WHERE y>4 ORDER BY rowid, w, x LIMIT 3; } -} {9 16 25 sort} +} {9 16 25 nosort} do_test where-6.24 { cksort { SELECT y FROM t1 WHERE y>=9 ORDER BY rowid, x DESC, w LIMIT 3; } -} {9 16 25 sort} +} {9 16 25 nosort} do_test where-6.25 { cksort { SELECT y FROM t1 WHERE y>4 AND y<25 ORDER BY rowid; @@ -619,7 +619,7 @@ do_test where-6.27 { cksort { SELECT y FROM t1 WHERE y<=25 ORDER BY _rowid_, w+y; } -} {4 9 16 25 sort} +} {4 9 16 25 nosort} # Tests for reverse-order sorting. @@ -793,7 +793,7 @@ do_test where-7.34 { cksort { SELECT y FROM t1 WHERE y<25 AND y>4 ORDER BY rowid DESC, y DESC } -} {16 9 sort} +} {16 9 nosort} do_test where-7.35 { cksort { SELECT y FROM t1 WHERE y<25 AND y>=4 ORDER BY rowid DESC @@ -874,7 +874,6 @@ do_test where-10.4 { # that array. # do_test where-11.1 { -btree_breakpoint execsql { CREATE TABLE t99(Dte INT, X INT); DELETE FROM t99 WHERE (Dte = 2451337) OR (Dte = 2451339) OR @@ -902,6 +901,143 @@ btree_breakpoint } } {} +# Ticket #2116: Make sure sorting by index works well with nn INTEGER PRIMARY +# KEY. +# +do_test where-12.1 { + execsql { + CREATE TABLE t6(a INTEGER PRIMARY KEY, b TEXT); + INSERT INTO t6 VALUES(1,'one'); + INSERT INTO t6 VALUES(4,'four'); + CREATE INDEX t6i1 ON t6(b); + } + cksort { + SELECT * FROM t6 ORDER BY b; + } +} {4 four 1 one nosort} +do_test where-12.2 { + cksort { + SELECT * FROM t6 ORDER BY b, a; + } +} {4 four 1 one nosort} +do_test where-12.3 { + cksort { + SELECT * FROM t6 ORDER BY a; + } +} {1 one 4 four nosort} +do_test where-12.4 { + cksort { + SELECT * FROM t6 ORDER BY a, b; + } +} {1 one 4 four nosort} +do_test where-12.5 { + cksort { + SELECT * FROM t6 ORDER BY b DESC; + } +} {1 one 4 four nosort} +do_test where-12.6 { + cksort { + SELECT * FROM t6 ORDER BY b DESC, a DESC; + } +} {1 one 4 four nosort} +do_test where-12.7 { + cksort { + SELECT * FROM t6 ORDER BY b DESC, a ASC; + } +} {1 one 4 four sort} +do_test where-12.8 { + cksort { + SELECT * FROM t6 ORDER BY b ASC, a DESC; + } +} {4 four 1 one sort} +do_test where-12.9 { + cksort { + SELECT * FROM t6 ORDER BY a DESC; + } +} {4 four 1 one nosort} +do_test where-12.10 { + cksort { + SELECT * FROM t6 ORDER BY a DESC, b DESC; + } +} {4 four 1 one nosort} +do_test where-12.11 { + cksort { + SELECT * FROM t6 ORDER BY a DESC, b ASC; + } +} {4 four 1 one nosort} +do_test where-12.12 { + cksort { + SELECT * FROM t6 ORDER BY a ASC, b DESC; + } +} {1 one 4 four nosort} +do_test where-13.1 { + execsql { + CREATE TABLE t7(a INTEGER PRIMARY KEY, b TEXT); + INSERT INTO t7 VALUES(1,'one'); + INSERT INTO t7 VALUES(4,'four'); + CREATE INDEX t7i1 ON t7(b); + } + cksort { + SELECT * FROM t7 ORDER BY b; + } +} {4 four 1 one nosort} +do_test where-13.2 { + cksort { + SELECT * FROM t7 ORDER BY b, a; + } +} {4 four 1 one nosort} +do_test where-13.3 { + cksort { + SELECT * FROM t7 ORDER BY a; + } +} {1 one 4 four nosort} +do_test where-13.4 { + cksort { + SELECT * FROM t7 ORDER BY a, b; + } +} {1 one 4 four nosort} +do_test where-13.5 { + cksort { + SELECT * FROM t7 ORDER BY b DESC; + } +} {1 one 4 four nosort} +do_test where-13.6 { + cksort { + SELECT * FROM t7 ORDER BY b DESC, a DESC; + } +} {1 one 4 four nosort} +do_test where-13.7 { + cksort { + SELECT * FROM t7 ORDER BY b DESC, a ASC; + } +} {1 one 4 four sort} +do_test where-13.8 { + cksort { + SELECT * FROM t7 ORDER BY b ASC, a DESC; + } +} {4 four 1 one sort} +do_test where-13.9 { + cksort { + SELECT * FROM t7 ORDER BY a DESC; + } +} {4 four 1 one nosort} +do_test where-13.10 { + cksort { + SELECT * FROM t7 ORDER BY a DESC, b DESC; + } +} {4 four 1 one nosort} +do_test where-13.11 { + cksort { + SELECT * FROM t7 ORDER BY a DESC, b ASC; + } +} {4 four 1 one nosort} +do_test where-13.12 { + cksort { + SELECT * FROM t7 ORDER BY a ASC, b DESC; + } +} {1 one 4 four nosort} + + integrity_check {where-99.0}