From: drh <> Date: Sat, 9 Mar 2024 00:38:57 +0000 (+0000) Subject: The NOT NULL strength reduction optimization should X-Git-Tag: version-3.45.2~5 X-Git-Url: http://git.ipfire.org/?a=commitdiff_plain;h=c70c328bb733b9f69484860d54d827fdef34b33a;p=thirdparty%2Fsqlite.git The NOT NULL strength reduction optimization should be applied to the WHERE clause only. FossilOrigin-Name: be266c713963d724802f5e9ad9d7d3c3d7f4daf1d95b63df6df1beb3a065bdab --- diff --git a/manifest b/manifest index 3cad1b5246..80717bc414 100644 --- a/manifest +++ b/manifest @@ -1,5 +1,5 @@ -C Silently\signore\sredundant\sON\sCONFLICT\sclauses\sin\san\sUPSERT. -D 2024-03-08T14:11:49.519 +C The\sNOT\sNULL\sstrength\sreduction\soptimization\sshould\nbe\sapplied\sto\sthe\sWHERE\sclause\sonly. +D 2024-03-09T00:38:57.614 F .fossil-settings/empty-dirs dbb81e8fc0401ac46a1491ab34a7f2c7c0452f2f06b54ebb845d024ca8283ef1 F .fossil-settings/ignore-glob 35175cdfcf539b2318cb04a9901442804be81cd677d8b889fcc9149c21f239ea F LICENSE.md df5091916dbb40e6e9686186587125e1b2ff51f022cc334e886c19a0e9982724 @@ -736,14 +736,14 @@ F src/pragma.h e690a356c18e98414d2e870ea791c1be1545a714ba623719deb63f7f226d8bb7 F src/prepare.c 371f6115cb69286ebc12c6f2d7511279c2e47d9f54f475d46a554d687a3b312c F src/printf.c d3392b2a20ee314ddeef34fb43c904bf4619eb20ff9a9e07e3950a7e4dcd6912 F src/random.c 606b00941a1d7dd09c381d3279a058d771f406c5213c9932bbd93d5587be4b9c -F src/resolve.c d873365b47b39e5e857f86bd8cc3effe7eb2d34f26e6fb07b4d01b0dca9c9481 +F src/resolve.c 446bcb8ebf0ea7066c2ca99e5336f0dbc9230ac76f80fafd1bfa82fe7871af2d F src/rowset.c 8432130e6c344b3401a8874c3cb49fefe6873fec593294de077afea2dce5ec97 F src/select.c f1a81ff4f8e9e76c224e2ab3a4baa799add0db22158c7fcede65d8cc4a6fa2da F src/shell.c.in c7e7e4812515403e5236c199859d9d87e8d4d25a65516eaede9f522726d16ce0 F src/sqlite.h.in 020d7b7307dda51420dc48b47e5334eaface77baba6bd9818375d392eb3ab5b5 F src/sqlite3.rc 5121c9e10c3964d5755191c80dd1180c122fc3a8 F src/sqlite3ext.h 3f046c04ea3595d6bfda99b781926b17e672fd6d27da2ba6d8d8fc39981dcb54 -F src/sqliteInt.h 30ebef1ff3fafa3323580454cbdcf53ff7f217da813907e86fe5f8849aba6980 +F src/sqliteInt.h 59e83fc2b01e7c7f550a9ab77fd5876a49f37acbf4cc01c031fc7947f95959d6 F src/sqliteLimit.h 6878ab64bdeb8c24a1d762d45635e34b96da21132179023338c93f820eee6728 F src/status.c cb11f8589a6912af2da3bb1ec509a94dd8ef27df4d4c1a97e0bcf2309ece972b F src/table.c 0f141b58a16de7e2fbe81c308379e7279f4c6b50eb08efeec5892794a0ba30d1 @@ -1439,7 +1439,7 @@ F test/notify1.test 669b2b743618efdc18ca4b02f45423d5d2304abf F test/notify2.test 2ecabaa1305083856b7c39cf32816b612740c161 F test/notify3.test 796c7b7157f55c93b4e672b724e9c923a6fc6aa72ac419379a623e2350472e22 F test/notnull.test a37b663d5bb728d66fc182016613fb8e4a0a4bbf3d75b8876a7527f7d4ed3f18 -F test/notnull2.test 1ee4acbd614d3cf5f1c4a52f5af7fc771b82352f1a51a86afeaa02c9df1d82ef +F test/notnull2.test 2ac7b4e04917148c7a1a9ed36df20150175ce942f07f5714375b29acbaca7106 F test/notnullfault.test fc4bb7845582a2b3db376001ef49118393b1b11abe0d24adb03db057ee2b73d5 F test/null.test b7ff206a1c60fe01aa2abd33ef9ea83c93727d993ca8a613de86e925c9f2bc6f F test/nulls1.test 7a5e4346ee4285034100b4cd20e6784f16a9d6c927e44ecdf10034086bbee9c9 @@ -2160,9 +2160,9 @@ F vsixtest/vsixtest.tcl 6a9a6ab600c25a91a7acc6293828957a386a8a93 F vsixtest/vsixtest.vcxproj.data 2ed517e100c66dc455b492e1a33350c1b20fbcdc F vsixtest/vsixtest.vcxproj.filters 37e51ffedcdb064aad6ff33b6148725226cd608e F vsixtest/vsixtest_TemporaryKey.pfx e5b1b036facdb453873e7084e1cae9102ccc67a0 -P f0a49dc8bc22d4889677d03beccda8f71f7374ae56b5c78f7395769f9272dc77 -Q +d0ea6b6ba64dba9d68c2b391ccf1171ea96fcdd7409dafdb2b697accb00246b8 -R 1898a37adb971b5c5f2becef52116f31 +P 46245855a0be1b4ed0efcde30f0919fb6361affc4443a4ed2fdac01ab6864df1 +Q +51704feae224eff601db5607f8651da11b3c2ed8a58ffe5b6ee8260cab50695b +R 89e8b7cfc0e2def34314b180eff025c2 U drh -Z 2dfcb7188615a8e6fd0ce28e38d620b0 +Z 1ba791fb27929b189c2404ced457cbb9 # Remove this line to create a well-formed Fossil manifest. diff --git a/manifest.uuid b/manifest.uuid index 9f789f0cd4..4746c86c2b 100644 --- a/manifest.uuid +++ b/manifest.uuid @@ -1 +1 @@ -46245855a0be1b4ed0efcde30f0919fb6361affc4443a4ed2fdac01ab6864df1 \ No newline at end of file +be266c713963d724802f5e9ad9d7d3c3d7f4daf1d95b63df6df1beb3a065bdab \ No newline at end of file diff --git a/src/resolve.c b/src/resolve.c index 6c37650289..24e47789b1 100644 --- a/src/resolve.c +++ b/src/resolve.c @@ -966,6 +966,19 @@ static int resolveExprStep(Walker *pWalker, Expr *pExpr){ ** resolved. This prevents "column" from being counted as having been ** referenced, which might prevent a SELECT from being erroneously ** marked as correlated. + ** + ** 2024-03-28: Beware of aggregates. A bare column of aggregated table + ** can still evaluate to NULL even though it is marked as NOT NULL. + ** Example: + ** + ** CREATE TABLE t1(a INT NOT NULL); + ** SELECT a, a IS NULL, a IS NOT NULL, count(*) FROM t1; + ** + ** The "a IS NULL" and "a IS NOT NULL" expressions cannot be optimized + ** here because at the time this case is hit, we do not yet know whether + ** or not t1 is being aggregated. We have to assume the worst and omit + ** the optimization. The only time it is safe to apply this optimization + ** is within the WHERE clause. */ case TK_NOTNULL: case TK_ISNULL: { @@ -976,19 +989,36 @@ static int resolveExprStep(Walker *pWalker, Expr *pExpr){ anRef[i] = p->nRef; } sqlite3WalkExpr(pWalker, pExpr->pLeft); - if( 0==sqlite3ExprCanBeNull(pExpr->pLeft) && !IN_RENAME_OBJECT ){ - testcase( ExprHasProperty(pExpr, EP_OuterON) ); - assert( !ExprHasProperty(pExpr, EP_IntValue) ); - pExpr->u.iValue = (pExpr->op==TK_NOTNULL); - pExpr->flags |= EP_IntValue; - pExpr->op = TK_INTEGER; + if( IN_RENAME_OBJECT ) return WRC_Prune; + if( sqlite3ExprCanBeNull(pExpr->pLeft) ){ + /* The expression can be NULL. So the optimization does not apply */ + return WRC_Prune; + } - for(i=0, p=pNC; p && ipNext, i++){ - p->nRef = anRef[i]; + for(i=0, p=pNC; p; p=p->pNext, i++){ + if( (p->ncFlags & NC_Where)==0 ){ + return WRC_Prune; /* Not in a WHERE clause. Unsafe to optimize. */ } - sqlite3ExprDelete(pParse->db, pExpr->pLeft); - pExpr->pLeft = 0; } + testcase( ExprHasProperty(pExpr, EP_OuterON) ); + assert( !ExprHasProperty(pExpr, EP_IntValue) ); +#if TREETRACE_ENABLED + if( sqlite3TreeTrace & 0x80000 ){ + sqlite3DebugPrintf( + "NOT NULL strength reduction converts the following to %d:\n", + pExpr->op==TK_NOTNULL + ); + sqlite3ShowExpr(pExpr); + } +#endif /* TREETRACE_ENABLED */ + pExpr->u.iValue = (pExpr->op==TK_NOTNULL); + pExpr->flags |= EP_IntValue; + pExpr->op = TK_INTEGER; + for(i=0, p=pNC; p && ipNext, i++){ + p->nRef = anRef[i]; + } + sqlite3ExprDelete(pParse->db, pExpr->pLeft); + pExpr->pLeft = 0; return WRC_Prune; } @@ -1888,7 +1918,9 @@ static int resolveSelectStep(Walker *pWalker, Select *p){ } if( sqlite3ResolveExprNames(&sNC, p->pHaving) ) return WRC_Abort; } + sNC.ncFlags |= NC_Where; if( sqlite3ResolveExprNames(&sNC, p->pWhere) ) return WRC_Abort; + sNC.ncFlags &= ~NC_Where; /* Resolve names in table-valued-function arguments */ for(i=0; ipSrc->nSrc; i++){ diff --git a/src/sqliteInt.h b/src/sqliteInt.h index 23004689fd..49cff8fc16 100644 --- a/src/sqliteInt.h +++ b/src/sqliteInt.h @@ -1123,6 +1123,7 @@ extern u32 sqlite3TreeTrace; ** 0x00010000 Beginning of DELETE/INSERT/UPDATE processing ** 0x00020000 Transform DISTINCT into GROUP BY ** 0x00040000 SELECT tree dump after all code has been generated +** 0x00080000 NOT NULL strength reduction */ /* @@ -3448,6 +3449,7 @@ struct NameContext { #define NC_InAggFunc 0x020000 /* True if analyzing arguments to an agg func */ #define NC_FromDDL 0x040000 /* SQL text comes from sqlite_schema */ #define NC_NoSelect 0x080000 /* Do not descend into sub-selects */ +#define NC_Where 0x100000 /* Processing WHERE clause of a SELECT */ #define NC_OrderAgg 0x8000000 /* Has an aggregate other than count/min/max */ /* diff --git a/test/notnull2.test b/test/notnull2.test index 7f68086810..09161efbdb 100644 --- a/test/notnull2.test +++ b/test/notnull2.test @@ -59,14 +59,14 @@ do_vmstep_test 1.4.2 { do_vmstep_test 1.5.1 { SELECT count(*) FROM t2 WHERE EXISTS( - SELECT t2.d IS NULL FROM t1 WHERE t1.a=450 + SELECT 1 FROM t1 WHERE t1.a=450 AND t2.d IS NULL ) -} 10000 {1000} +} 7000 {0} do_vmstep_test 1.5.2 { SELECT count(*) FROM t2 WHERE EXISTS( - SELECT t2.c IS NULL FROM t1 WHERE t1.a=450 + SELECT 1 FROM t1 WHERE t1.a=450 AND t2.c IS NULL ) -} +100000 {1000} +} +8000 {0} #------------------------------------------------------------------------- reset_db @@ -111,4 +111,12 @@ do_execsql_test 4.1 { SELECT * FROM (SELECT 3 AS c FROM t1) AS t3 LEFT JOIN t2 ON c IS NULL; } {3 {}} +# 2024-03-08 https://sqlite.org/forum/forumpost/440f2a2f17 +# +reset_db +do_execsql_test 5.0 { + CREATE TABLE t1(a INT NOT NULL); + SELECT a IS NULL, a IS NOT NULL, count(*) FROM t1; +} {1 0 0} + finish_test