From: drh Date: Fri, 9 Mar 2012 22:02:08 +0000 (+0000) Subject: Candidate fix for the optimizer problem described in ticket X-Git-Tag: version-3.7.11~13 X-Git-Url: http://git.ipfire.org/?a=commitdiff_plain;h=331b67c151b210d60b986af9a2cc845b90ea0221;p=thirdparty%2Fsqlite.git Candidate fix for the optimizer problem described in ticket [b7c8682cc17f3] which can causes a LEFT JOIN to be changed into a INNER JOIN if there are OR terms in the WHERE clause. FossilOrigin-Name: 0dc4cb935514131c99172175d57feec3a1743aa9 --- diff --git a/manifest b/manifest index 57d069eb0a..ff717fe1dd 100644 --- a/manifest +++ b/manifest @@ -1,5 +1,5 @@ -C On\sWindows,\smake\ssure\sthe\sreturned\stest\scurrent\sdirectory\svalue\sdoes\snot\scontain\sany\sbackslashes. -D 2012-03-08T20:28:31.444 +C Candidate\sfix\sfor\sthe\soptimizer\sproblem\sdescribed\sin\sticket\s\n[b7c8682cc17f3]\swhich\scan\scauses\sa\sLEFT\sJOIN\sto\sbe\schanged\ninto\sa\sINNER\sJOIN\sif\sthere\sare\sOR\sterms\sin\sthe\sWHERE\sclause. +D 2012-03-09T22:02:08.875 F Makefile.arm-wince-mingw32ce-gcc d6df77f1f48d690bd73162294bbba7f59507c72f F Makefile.in 2f37e468503dbe79d35c9f6dffcf3fae1ae9ec20 F Makefile.linux-gcc 91d710bdc4998cb015f39edf3cb314ec4f4d7e23 @@ -253,7 +253,7 @@ F src/vtab.c ab90fb600a3f5e4b7c48d22a4cdb2d6b23239847 F src/wal.c 7bb3ad807afc7973406c805d5157ec7a2f65e146 F src/wal.h 29c197540b19044e6cd73487017e5e47a1d3dac6 F src/walker.c 3112bb3afe1d85dc52317cb1d752055e9a781f8f -F src/where.c f2cf59751f7facb4c422adf83ddc989aa5772874 +F src/where.c d4ce63a2887dab037d9d9830abbfcac2643e308a F test/8_3_names.test 631ea964a3edb091cf73c3b540f6bcfdb36ce823 F test/aggerror.test a867e273ef9e3d7919f03ef4f0e8c0d2767944f2 F test/alias.test 4529fbc152f190268a15f9384a5651bbbabc9d87 @@ -937,10 +937,10 @@ F test/where3.test 667e75642102c97a00bf9b23d3cb267db321d006 F test/where4.test e9b9e2f2f98f00379e6031db6a6fca29bae782a2 F test/where5.test fdf66f96d29a064b63eb543e28da4dfdccd81ad2 F test/where6.test 5da5a98cec820d488e82708301b96cb8c18a258b -F test/where7.test 814d7373413398e074f134cff5f8872e2c08bd3b +F test/where7.test 5c566388f0cc318b0032ce860f4ac5548e3c265a F test/where8.test a6c740fd286d7883e274e17b6230a9d672a7ab1f F test/where8m.test da346596e19d54f0aba35ebade032a7c47d79739 -F test/where9.test cd4ee5e455799ddba7041e5ac539044bb24e3874 +F test/where9.test ae98dc22ef9b6f2bc81e9f164e41b38faa9bda06 F test/whereA.test 24c234263c8fe358f079d5e57d884fb569d2da0a F test/whereB.test 0def95db3bdec220a731c7e4bec5930327c1d8c5 F test/whereC.test 13ff5ec0dba407c0e0c075980c75b3275a6774e5 @@ -992,7 +992,7 @@ F tool/tostr.awk e75472c2f98dd76e06b8c9c1367f4ab07e122d06 F tool/vdbe-compress.tcl d70ea6d8a19e3571d7ab8c9b75cba86d1173ff0f F tool/warnings-clang.sh 9f406d66e750e8ac031c63a9ef3248aaa347ef2a F tool/warnings.sh fbc018d67fd7395f440c28f33ef0f94420226381 -P 82bcd7ec1531f6d71c079578434c58d3ce46a1de -R 481f07eae7a20043918617293f6bf255 -U mistachkin -Z e4b7999e3f65d6915663c98d5d60a2e1 +P efee39e64bd95c284220fdb0ae8ee6c1847fadab +R bea1320a1e93f035f866bb48777a9a0b +U drh +Z baafcf2bb8e1f4793d13146917501256 diff --git a/manifest.uuid b/manifest.uuid index 65ab8c5d21..b0f211922a 100644 --- a/manifest.uuid +++ b/manifest.uuid @@ -1 +1 @@ -efee39e64bd95c284220fdb0ae8ee6c1847fadab \ No newline at end of file +0dc4cb935514131c99172175d57feec3a1743aa9 \ No newline at end of file diff --git a/src/where.c b/src/where.c index eda8d5fb8e..1def2db917 100644 --- a/src/where.c +++ b/src/where.c @@ -4342,10 +4342,25 @@ static Bitmask codeOneLoopStart( ** Then for every term xN, evaluate as the subexpression: xN AND z ** That way, terms in y that are factored into the disjunction will ** be picked up by the recursive calls to sqlite3WhereBegin() below. + ** + ** Actually, each subexpression is converted to "xN AND w" where w is + ** the "interesting" terms of z - terms that did not originate in the + ** ON or USING clause of a LEFT JOIN, and terms that are usable as + ** indices. */ if( pWC->nTerm>1 ){ - pAndExpr = sqlite3ExprAlloc(pParse->db, TK_AND, 0, 0); - pAndExpr->pRight = pWhere; + int ii; + for(ii=0; iinTerm; ii++){ + Expr *pExpr = pWC->a[ii].pExpr; + if( ExprHasProperty(pExpr, EP_FromJoin) ) continue; + if( pWC->a[ii].wtFlags & (TERM_VIRTUAL|TERM_ORINFO) ) continue; + if( (pWC->a[ii].eOperator & WO_ALL)==0 ) continue; + pExpr = sqlite3ExprDup(pParse->db, pExpr, 0); + pAndExpr = sqlite3ExprAnd(pParse->db, pAndExpr, pExpr); + } + if( pAndExpr ){ + pAndExpr = sqlite3PExpr(pParse, TK_AND, 0, pAndExpr, 0); + } } for(ii=0; iinTerm; ii++){ @@ -4387,7 +4402,10 @@ static Bitmask codeOneLoopStart( } } } - sqlite3DbFree(pParse->db, pAndExpr); + if( pAndExpr ){ + pAndExpr->pLeft = 0; + sqlite3ExprDelete(pParse->db, pAndExpr); + } sqlite3VdbeChangeP1(v, iRetInit, sqlite3VdbeCurrentAddr(v)); sqlite3VdbeAddOp2(v, OP_Goto, 0, pLevel->addrBrk); sqlite3VdbeResolveLabel(v, iLoopBody); diff --git a/test/where7.test b/test/where7.test index ffb7173d21..b6cd7ccbbc 100644 --- a/test/where7.test +++ b/test/where7.test @@ -23339,7 +23339,7 @@ do_execsql_test where7-3.1 { OR t301.c8 = 1407424651264000) ORDER BY t302.c5 LIMIT 200; } { - 0 0 1 {SEARCH TABLE t301 USING COVERING INDEX t301_c4 (c4=?) (~5 rows)} + 0 0 1 {SEARCH TABLE t301 USING COVERING INDEX t301_c4 (c4=?) (~10 rows)} 0 0 1 {SEARCH TABLE t301 USING INTEGER PRIMARY KEY (rowid=?) (~1 rows)} 0 1 0 {SEARCH TABLE t302 USING INDEX t302_c8_c3 (c8=? AND c3>?) (~2 rows)} 0 0 0 {USE TEMP B-TREE FOR ORDER BY} diff --git a/test/where9.test b/test/where9.test index 8c5c96e2a8..23260a6b65 100644 --- a/test/where9.test +++ b/test/where9.test @@ -364,7 +364,7 @@ ifcapable explain { } { 0 0 0 {SEARCH TABLE t1 USING INTEGER PRIMARY KEY (rowid=?) (~1 rows)} 0 1 1 {SEARCH TABLE t2 USING INDEX t2d (d=?) (~2 rows)} - 0 1 1 {SEARCH TABLE t2 USING COVERING INDEX t2f (f=?) (~5 rows)} + 0 1 1 {SEARCH TABLE t2 USING COVERING INDEX t2f (f=?) (~10 rows)} } do_execsql_test where9-3.2 { EXPLAIN QUERY PLAN @@ -374,7 +374,7 @@ ifcapable explain { } { 0 0 0 {SEARCH TABLE t1 USING INTEGER PRIMARY KEY (rowid=?) (~1 rows)} 0 1 1 {SEARCH TABLE t2 USING INDEX t2d (d=?) (~2 rows)} - 0 1 1 {SEARCH TABLE t2 USING COVERING INDEX t2f (f=?) (~5 rows)} + 0 1 1 {SEARCH TABLE t2 USING COVERING INDEX t2f (f=?) (~10 rows)} } } @@ -453,8 +453,8 @@ ifcapable explain { do_execsql_test where9-5.1 { EXPLAIN QUERY PLAN SELECT a FROM t1 WHERE b>1000 AND (c=31031 OR d IS NULL) } { - 0 0 0 {SEARCH TABLE t1 USING INDEX t1c (c=?) (~2 rows)} - 0 0 0 {SEARCH TABLE t1 USING INDEX t1d (d=?) (~2 rows)} + 0 0 0 {SEARCH TABLE t1 USING INDEX t1c (c=?) (~3 rows)} + 0 0 0 {SEARCH TABLE t1 USING INDEX t1d (d=?) (~3 rows)} } # In contrast, b=1000 is preferred over any OR-clause. @@ -856,5 +856,25 @@ do_test where9-7.3.2 { } } {79 81} +# Fix for ticket [b7c8682cc17f32903f03a610bd0d35ffd3c1e6e4] +# "Incorrect result from LEFT JOIN with OR in the WHERE clause" +# +do_test where9-8.1 { + db eval { + CREATE TABLE t81(a INTEGER PRIMARY KEY, b, c, d); + CREATE TABLE t82(x INTEGER PRIMARY KEY, y); + CREATE TABLE t83(p INTEGER PRIMARY KEY, q); + + INSERT INTO t81 VALUES(2,3,4,5); + INSERT INTO t81 VALUES(3,4,5,6); + INSERT INTO t82 VALUES(2,4); + INSERT INTO t83 VALUES(5,55); + + SELECT * + FROM t81 LEFT JOIN t82 ON y=b JOIN t83 + WHERE c==p OR d==p + ORDER BY +a; + } +} {2 3 4 5 {} {} 5 55 3 4 5 6 2 4 5 55} finish_test