From: drh Date: Fri, 24 Apr 2009 14:51:42 +0000 (+0000) Subject: Make sure that the optimizer realizes that an "x IS NULL" contraint does not X-Git-Tag: version-3.6.15~205 X-Git-Url: http://git.ipfire.org/cgi-bin/gitweb.cgi?a=commitdiff_plain;h=46619d67873a20d83e298246d428ef695b91720c;p=thirdparty%2Fsqlite.git Make sure that the optimizer realizes that an "x IS NULL" contraint does not necessarily give a single-row result even on a UNIQUE index. Ticket #3824. (CVS 6545) FossilOrigin-Name: 207335fdbf992a2f5bc5982b3163a38016ba1b21 --- diff --git a/manifest b/manifest index 6f59881380..a156c10e86 100644 --- a/manifest +++ b/manifest @@ -1,5 +1,5 @@ -C Make\sselecting\sthe\sasynchronous\sIO\sfile-locking\smode\sa\sruntime\soperation.\sStill\suntested.\s(CVS\s6544) -D 2009-04-24T10:13:06 +C Make\ssure\sthat\sthe\soptimizer\srealizes\sthat\san\s"x\sIS\sNULL"\scontraint\sdoes\snot\nnecessarily\sgive\sa\ssingle-row\sresult\seven\son\sa\sUNIQUE\sindex.\s\sTicket\s#3824.\s(CVS\s6545) +D 2009-04-24T14:51:42 F Makefile.arm-wince-mingw32ce-gcc fcd5e9cd67fe88836360bb4f9ef4cb7f8e2fb5a0 F Makefile.in 583e87706abc3026960ed759aff6371faf84c211 F Makefile.linux-gcc d53183f4aa6a9192d249731c90dbdffbd2c68654 @@ -212,7 +212,7 @@ F src/vdbeblob.c e67757450ae8581a8b354d9d7e467e41502dfe38 F src/vdbemem.c 111d8193859d16aefd5d3cb57472808584ea5503 F src/vtab.c 6118d71c5137e20a7ac51fb5d9beb0361fbedb89 F src/walker.c 7cdf63223c953d4343c6833e940f110281a378ee -F src/where.c 6f7199cff0f05934bdadd6c67a0c14c0cbf5bcb4 +F src/where.c 5eaf44228221e541911fb530d6dceb1e0e37157f F test/aggerror.test a867e273ef9e3d7919f03ef4f0e8c0d2767944f2 F test/alias.test 4529fbc152f190268a15f9384a5651bbbabc9d87 F test/all.test 14165b3e32715b700b5f0cbf8f6e3833dda0be45 @@ -643,6 +643,7 @@ F test/tkt3762.test 2a9f3b03df44ec49ec0cfa8d5da6574c2a7853df F test/tkt3773.test 430b06567ce40285dfd2c4834a2a61816403efeb F test/tkt3791.test a6624b9a80b216a26cf473607f42f3e51898c267 F test/tkt3793.test 3aa2efe55bc31fc9459618feea2016ea9a52b2af +F test/tkt3824.test df7c288c9b50c0ef531e56907bb2eed4aa1a4705 F test/tokenize.test ce430a7aed48fc98301611429595883fdfcab5d7 F test/trace.test 19ffbc09885c3321d56358a5738feae8587fb377 F test/trans.test 8b79967a7e085289ec64890c6fdf9d089e1b4a5f @@ -723,7 +724,7 @@ F tool/speedtest16.c c8a9c793df96db7e4933f0852abb7a03d48f2e81 F tool/speedtest2.tcl ee2149167303ba8e95af97873c575c3e0fab58ff F tool/speedtest8.c 2902c46588c40b55661e471d7a86e4dd71a18224 F tool/speedtest8inst1.c 293327bc76823f473684d589a8160bde1f52c14e -P 92bc6be2a86f8a68ceded2bc08fe7d6ff23b56fb -R d1fe56ed7757cac24f050d623f1a6f33 -U danielk1977 -Z 741711df9244c68ea2afca1186c054bc +P 577277e84a05707b8c21aa08bc5fc314c1ac38ac +R 0206ac4aa85a991e57e63aae8cfedcce +U drh +Z c576963fd7ebe23db6a9694028a5b0e6 diff --git a/manifest.uuid b/manifest.uuid index d20afd5002..f9e768ccef 100644 --- a/manifest.uuid +++ b/manifest.uuid @@ -1 +1 @@ -577277e84a05707b8c21aa08bc5fc314c1ac38ac \ No newline at end of file +207335fdbf992a2f5bc5982b3163a38016ba1b21 \ No newline at end of file diff --git a/src/where.c b/src/where.c index 3fa674d11a..508c634d41 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.388 2009/04/23 13:22:44 drh Exp $ +** $Id: where.c,v 1.389 2009/04/24 14:51:42 drh Exp $ */ #include "sqliteInt.h" @@ -226,11 +226,12 @@ struct WhereCost { */ #define WHERE_ROWID_EQ 0x00001000 /* rowid=EXPR or rowid IN (...) */ #define WHERE_ROWID_RANGE 0x00002000 /* rowidEXPR */ -#define WHERE_COLUMN_EQ 0x00010000 /* x=EXPR or x IN (...) */ +#define WHERE_COLUMN_EQ 0x00010000 /* x=EXPR or x IN (...) or x IS NULL */ #define WHERE_COLUMN_RANGE 0x00020000 /* xEXPR */ #define WHERE_COLUMN_IN 0x00040000 /* x IN (...) */ -#define WHERE_INDEXED 0x00070000 /* Anything that uses an index */ -#define WHERE_IN_ABLE 0x00071000 /* Able to support an IN operator */ +#define WHERE_COLUMN_NULL 0x00080000 /* x IS NULL */ +#define WHERE_INDEXED 0x000f0000 /* Anything that uses an index */ +#define WHERE_IN_ABLE 0x000f1000 /* Able to support an IN operator */ #define WHERE_TOP_LIMIT 0x00100000 /* xEXPR or x>=EXPR constraint */ #define WHERE_IDX_ONLY 0x00800000 /* Use index only - omit table */ @@ -2030,9 +2031,10 @@ static void bestBtreeIndex( WHERETRACE(("... index %s:\n", pProbe->zName)); /* Count the number of columns in the index that are satisfied - ** by x=EXPR constraints or x IN (...) constraints. For a term - ** of the form x=EXPR we only have to do a single binary search. - ** But for x IN (...) we have to do a number of binary searched + ** by x=EXPR or x IS NULL constraints or x IN (...) constraints. + ** For a term of the form x=EXPR or x IS NULL we only have to do + ** a single binary search. But for x IN (...) we have to do a + ** number of binary searched ** equal to the number of entries on the RHS of the IN operator. ** The inMultipler variable with try to estimate the number of ** binary searches needed. @@ -2052,6 +2054,8 @@ static void bestBtreeIndex( }else if( pExpr->x.pList ){ inMultiplier *= pExpr->x.pList->nExpr + 1; } + }else if( pTerm->eOperator & WO_ISNULL ){ + wsFlags |= WHERE_COLUMN_NULL; } } nRow = pProbe->aiRowEst[i] * inMultiplier; @@ -2064,9 +2068,12 @@ static void bestBtreeIndex( } cost = nRow + inMultiplier*estLog(pProbe->aiRowEst[0]); nEq = i; - if( pProbe->onError!=OE_None && (wsFlags & WHERE_COLUMN_IN)==0 - && nEq==pProbe->nColumn ){ - wsFlags |= WHERE_UNIQUE; + if( pProbe->onError!=OE_None && nEq==pProbe->nColumn ){ + testcase( wsFlags & WHERE_COLUMN_IN ); + testcase( wsFlags & WHERE_COLUMN_NULL ); + if( (wsFlags & (WHERE_COLUMN_IN|WHERE_COLUMN_NULL))==0 ){ + wsFlags |= WHERE_UNIQUE; + } } WHERETRACE(("...... nEq=%d inMult=%.9g nRow=%.9g cost=%.9g\n", nEq, inMultiplier, nRow, cost)); @@ -2097,8 +2104,9 @@ static void bestBtreeIndex( /* Add the additional cost of sorting if that is a factor. */ if( pOrderBy ){ - if( (wsFlags & WHERE_COLUMN_IN)==0 && - isSortingIndex(pParse,pWC->pMaskSet,pProbe,iCur,pOrderBy,nEq,&rev) ){ + if( (wsFlags & (WHERE_COLUMN_IN|WHERE_COLUMN_NULL))==0 + && isSortingIndex(pParse,pWC->pMaskSet,pProbe,iCur,pOrderBy,nEq,&rev) + ){ if( wsFlags==0 ){ wsFlags = WHERE_COLUMN_RANGE; } diff --git a/test/tkt3824.test b/test/tkt3824.test new file mode 100644 index 0000000000..1dccd9e690 --- /dev/null +++ b/test/tkt3824.test @@ -0,0 +1,88 @@ +# 2009 April 24 +# +# 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. +# +#*********************************************************************** +# +# Ticket #3824 +# +# When you use an "IS NULL" constraint on a UNIQUE index, the result +# is not necessarily UNIQUE. Make sure the optimizer does not assume +# uniqueness. +# +# $Id: tkt3824.test,v 1.1 2009/04/24 14:51:42 drh Exp $ + +set testdir [file dirname $argv0] +source $testdir/tester.tcl + +proc execsql_status {sql {db db}} { + set result [uplevel $db eval [list $sql]] + if {[db status sort]} { + concat $result sort + } else { + concat $result nosort + } +} + +do_test tkt3824-1.1 { + db eval { + CREATE TABLE t1(a,b); + INSERT INTO t1 VALUES(1,NULL); + INSERT INTO t1 VALUES(9,NULL); + INSERT INTO t1 VALUES(5,NULL); + INSERT INTO t1 VALUES(123,NULL); + INSERT INTO t1 VALUES(-10,NULL); + CREATE UNIQUE INDEX t1b ON t1(b); + } + execsql_status { + SELECT a FROM t1 WHERE b IS NULL ORDER BY a; + } +} {-10 1 5 9 123 sort} +do_test tkt3824-1.2 { + execsql_status { + SELECT a FROM t1 WHERE b IS NULL ORDER BY b, a; + } +} {-10 1 5 9 123 sort} + +do_test tkt3824-2.1 { + db eval { + CREATE TABLE t2(a,b,c); + INSERT INTO t2 VALUES(1,1,NULL); + INSERT INTO t2 VALUES(9,2,NULL); + INSERT INTO t2 VALUES(5,2,NULL); + INSERT INTO t2 VALUES(123,3,NULL); + INSERT INTO t2 VALUES(-10,3,NULL); + CREATE UNIQUE INDEX t2bc ON t2(b,c); + } + execsql_status { + SELECT a FROM t2 WHERE b=2 AND c IS NULL ORDER BY a; + } +} {5 9 sort} +do_test tkt3824-2.2 { + execsql_status { + SELECT a FROM t2 WHERE b=2 AND c IS NULL ORDER BY b, a; + } +} {5 9 sort} +do_test tkt3824-2.3 { + lsort [execsql_status { + SELECT a FROM t2 WHERE b=2 AND c IS NULL ORDER BY b; + }] +} {5 9 sort} + +do_test tkt3824-3.1 { + db eval { + CREATE TABLE t3(x,y); + INSERT INTO t3 SELECT a, b FROM t1; + INSERT INTO t3 VALUES(234,567); + CREATE UNIQUE INDEX t3y ON t3(y); + DELETE FROM t3 WHERE y IS NULL; + SELECT * FROM t3; + } +} {234 567} + +finish_test