From: drh <> Date: Mon, 13 Jun 2022 12:42:24 +0000 (+0000) Subject: Do not remove the EP_CanBeNull flag from expressions during a LEFT JOIN X-Git-Tag: version-3.39.0~37 X-Git-Url: http://git.ipfire.org/?a=commitdiff_plain;h=92d1afba9bc387015a679606aba342da925e8de5;p=thirdparty%2Fsqlite.git Do not remove the EP_CanBeNull flag from expressions during a LEFT JOIN strength reduction if the query also contains a RIGHT JOIN. Fix for the problem identified by [forum/forumpost/b40696f50145d21c|forum post b40696f50145d21c]. FossilOrigin-Name: b1be2259e2e08ec22a88bc9a18b3ab4d83246ad4c635c05cdf80d3eff84df06a --- diff --git a/manifest b/manifest index aedf7206a2..0d7cb7378d 100644 --- a/manifest +++ b/manifest @@ -1,5 +1,5 @@ -C The\ssame\srestrictions\son\sthe\suse\sof\sWHERE\sclause\sterms\sto\sdrive\sindexes\nin\sthe\spresence\sof\sRIGHT\sJOINs\salso\sapply\sto\sthe\suse\sof\sWHERE\sclause\sterms\nto\smanufacture\sautomatic\sindexes.\s\sThis\sfixes\sa\sproblem\sidentified\sby\n[forum:/forumpost/51e6959f61|forum\spost\s51e6959f61]. -D 2022-06-10T16:41:54.319 +C Do\snot\sremove\sthe\sEP_CanBeNull\sflag\sfrom\sexpressions\sduring\sa\sLEFT\sJOIN\nstrength\sreduction\sif\sthe\squery\salso\scontains\sa\sRIGHT\sJOIN.\sFix\sfor\nthe\sproblem\sidentified\sby\n[forum/forumpost/b40696f50145d21c|forum\spost\sb40696f50145d21c]. +D 2022-06-13T12:42:24.645 F .fossil-settings/empty-dirs dbb81e8fc0401ac46a1491ab34a7f2c7c0452f2f06b54ebb845d024ca8283ef1 F .fossil-settings/ignore-glob 35175cdfcf539b2318cb04a9901442804be81cd677d8b889fcc9149c21f239ea F LICENSE.md df5091916dbb40e6e9686186587125e1b2ff51f022cc334e886c19a0e9982724 @@ -570,7 +570,7 @@ F src/printf.c 6166a30417b05c5b2f82e1f183f75faa2926ad60531c0b688a57dbc951441a20 F src/random.c 097dc8b31b8fba5a9aca1697aeb9fd82078ec91be734c16bffda620ced7ab83c F src/resolve.c a4eb3c617027fd049b07432f3b942ea7151fa793a332a11a7d0f58c9539e104f F src/rowset.c ba9515a922af32abe1f7d39406b9d35730ed65efab9443dc5702693b60854c92 -F src/select.c 66ef4e23fea38c3306c948d0c6416862cc0ed07a01d6affba2a91001de41eec6 +F src/select.c ee3113de67330163a35307eacb4188b6778fcae1e2d2f738a9dda2daa0346e24 F src/shell.c.in 08e59f1cb9d9b1180aba52861aaada0c95f6ddd210488719684e160a0724c806 F src/sqlite.h.in 172528c287399a34f188154017b7268bf82c6d5b780902e361958d2318c4e37c F src/sqlite3.rc 5121c9e10c3964d5755191c80dd1180c122fc3a8 @@ -1167,7 +1167,7 @@ F test/join4.test 1a352e4e267114444c29266ce79e941af5885916 F test/join5.test d22b6cba8fb59ab3f1c82701434c360705eb12d4ce200c449f37b018fc47681a F test/join6.test f809c025fa253f9e150c0e9afd4cef8813257bceeb6f46e04041228c9403cc2c F test/join7.test 2268dcbb54b724391dda3748ea95c60d960607ffeed67885675998e7117697f6 -F test/join8.test 135277faf0cab04efe42bfea9aadde034bd36dc2ce3a3de49e97c8c7f745f103 +F test/join8.test aa3294b62e6a2a7622dbab864ac924820af910309835013ffac8421c733e9f8f F test/join9.test 9056ddd3b0c0f4f9d658f4521038d9a37dc23ead8ca9a505d0b0db2b6a471e05 F test/joinA.test 7eab225dc1c1ab258a5e62513a4ed7cabbd3db971d59d5d92f4fb6fa14c12f6a F test/joinB.test 1b2ba3fc8568b49411787fccbf540570c148e9b6a53a30f80691cb6268098ded @@ -1976,8 +1976,8 @@ F vsixtest/vsixtest.tcl 6a9a6ab600c25a91a7acc6293828957a386a8a93 F vsixtest/vsixtest.vcxproj.data 2ed517e100c66dc455b492e1a33350c1b20fbcdc F vsixtest/vsixtest.vcxproj.filters 37e51ffedcdb064aad6ff33b6148725226cd608e F vsixtest/vsixtest_TemporaryKey.pfx e5b1b036facdb453873e7084e1cae9102ccc67a0 -P e25dad868f9ef2c7847319c9f6f106999ba8b0a3e09ed9edfbd25e8fc6f3c10e -R 71f93056490b18abe7ae590f710ffb97 +P 342c501f532523347e6c339351e02043dd6ee9e11a291224b65ea72bd6c2ba40 +R a249dd322f3d0191f7349eb16a9ed1fc U drh -Z c3464bb306b9115d0a59088775264fcc +Z 7bab454819c3e667fed9b310a0634268 # Remove this line to create a well-formed Fossil manifest. diff --git a/manifest.uuid b/manifest.uuid index a8f0322faf..7a1cda9eb4 100644 --- a/manifest.uuid +++ b/manifest.uuid @@ -1 +1 @@ -342c501f532523347e6c339351e02043dd6ee9e11a291224b65ea72bd6c2ba40 \ No newline at end of file +b1be2259e2e08ec22a88bc9a18b3ab4d83246ad4c635c05cdf80d3eff84df06a \ No newline at end of file diff --git a/src/select.c b/src/select.c index 92dbea889f..e4a32efb78 100644 --- a/src/select.c +++ b/src/select.c @@ -429,15 +429,21 @@ void sqlite3SetJoinExpr(Expr *p, int iTable, u32 joinFlag){ ** an ordinary term that omits the EP_OuterON mark. ** ** This happens when a LEFT JOIN is simplified into an ordinary JOIN. +** +** If nullable is true, that means that Expr p might evaluate to NULL even +** if it is a reference to a NOT NULL column. This can happen, for example, +** if the table that p references is on the left side of a RIGHT JOIN. +** If nullable is true, then take care to not remove the EP_CanBeNull bit. +** See forum thread https://sqlite.org/forum/forumpost/b40696f50145d21c */ -static void unsetJoinExpr(Expr *p, int iTable){ +static void unsetJoinExpr(Expr *p, int iTable, int nullable){ while( p ){ if( ExprHasProperty(p, EP_OuterON) && (iTable<0 || p->w.iJoin==iTable) ){ ExprClearProperty(p, EP_OuterON); ExprSetProperty(p, EP_InnerON); } - if( p->op==TK_COLUMN && p->iTable==iTable ){ + if( p->op==TK_COLUMN && p->iTable==iTable && !nullable ){ ExprClearProperty(p, EP_CanBeNull); } if( p->op==TK_FUNCTION ){ @@ -445,11 +451,11 @@ static void unsetJoinExpr(Expr *p, int iTable){ if( p->x.pList ){ int i; for(i=0; ix.pList->nExpr; i++){ - unsetJoinExpr(p->x.pList->a[i].pExpr, iTable); + unsetJoinExpr(p->x.pList->a[i].pExpr, iTable, nullable); } } } - unsetJoinExpr(p->pLeft, iTable); + unsetJoinExpr(p->pLeft, iTable, nullable); p = p->pRight; } } @@ -5067,7 +5073,7 @@ static int pushDownWhereTerms( while( pSubq ){ SubstContext x; pNew = sqlite3ExprDup(pParse->db, pWhere, 0); - unsetJoinExpr(pNew, -1); + unsetJoinExpr(pNew, -1, 1); x.pParse = pParse; x.iTable = pSrc->iCursor; x.iNewTable = pSrc->iCursor; @@ -6751,7 +6757,8 @@ int sqlite3Select( SELECTTRACE(0x100,pParse,p, ("LEFT-JOIN simplifies to JOIN on term %d\n",i)); pItem->fg.jointype &= ~(JT_LEFT|JT_OUTER); - unsetJoinExpr(p->pWhere, pItem->iCursor); + unsetJoinExpr(p->pWhere, pItem->iCursor, + pTabList->a[0].fg.jointype & JT_LTORJ); } /* No futher action if this term of the FROM clause is no a subquery */ diff --git a/test/join8.test b/test/join8.test index af6f4913c1..1706bbdce1 100644 --- a/test/join8.test +++ b/test/join8.test @@ -694,6 +694,39 @@ do_execsql_test join8-22000 { RIGHT JOIN t4 ON true WHERE a=b; } {} - + +# 2022-06-13 +# https://sqlite.org/forum/forumpost/b40696f501 +# +# This optimization that converts "x ISNULL" into "FALSE" when column "x" has a +# NOT NULL constraint is too aggresive if the query contains RIGHT JOIN. +# +reset_db +db null - +do_execsql_test join8-23000 { + CREATE TABLE t1(a TEXT); + INSERT INTO t1 VALUES('c'); + CREATE TABLE t2(b TEXT, c TEXT NOT NULL); + INSERT INTO t2 VALUES('a', 'b'); + CREATE TABLE t3(d TEXT); + INSERT INTO t3 VALUES('x'); + CREATE TABLE t4(e TEXT); + INSERT INTO t4 VALUES('y'); +} +do_execsql_test join8-23010 { + SELECT * + FROM t1 + LEFT JOIN t2 ON TRUE + JOIN t3 ON c='' + RIGHT JOIN t4 ON b=''; +} {- - - - y} +do_execsql_test join8-23020 { + SELECT * + FROM t1 + LEFT JOIN t2 ON TRUE + JOIN t3 ON c='' + RIGHT JOIN t4 ON b='' + WHERE d ISNULL +} {- - - - y} finish_test