diff --git a/manifest b/manifest index ab0ad06cfb..6ec713d5fa 100644 --- a/manifest +++ b/manifest @@ -1,5 +1,5 @@ -C Add\sa\sfew\ssimple\stest\scases\sfor\sMATERIALIZED\sand\sNOT\sMATERIALIZED. -D 2021-02-22T19:57:58.697 +C Allow\sWHERE\sterms\sto\sbe\spushed\sdown\sinto\ssub-queries\sthat\scontain\swindow\sfunctions,\sprovided\sthat\sthe\sWHERE\sterm\sis\smade\sup\sof\sentirely\sof\sconstants\sand\scopies\sof\sexpressions\sfound\sin\sthe\sPARTITION\sBY\sclauses\sof\sall\swindow\sfunctions\sin\sthe\ssub-query. +D 2021-02-23T15:53:22.797 F .fossil-settings/empty-dirs dbb81e8fc0401ac46a1491ab34a7f2c7c0452f2f06b54ebb845d024ca8283ef1 F .fossil-settings/ignore-glob 35175cdfcf539b2318cb04a9901442804be81cd677d8b889fcc9149c21f239ea F LICENSE.md df5091916dbb40e6e9686186587125e1b2ff51f022cc334e886c19a0e9982724 @@ -542,12 +542,12 @@ F src/printf.c 10e61ec79dd9d41fdc77afee4e0df04fbb427f309c043118fe0b26a7d7db488a F src/random.c 80f5d666f23feb3e6665a6ce04c7197212a88384 F src/resolve.c c263fa5b255a03314c2418f936386e903d01c3e7cbec25a363a586ef3f10b249 F src/rowset.c ba9515a922af32abe1f7d39406b9d35730ed65efab9443dc5702693b60854c92 -F src/select.c 09f15067366d8276c7444badc82863cae782e241ab1636c4bea8137dc61451e4 +F src/select.c 5d66f394afb481eb812927283a3036f7ffbda48442e3a0517d1fa1c3248aca8c F src/shell.c.in 844417f84df1f6c4fce1c815629a888cfdcf219e86513e9c332bbcc38832f477 F src/sqlite.h.in 8855a19f37ade8dad189a9e48233a2ebe1b46faf469c7eb0906a654e252dcc57 F src/sqlite3.rc 5121c9e10c3964d5755191c80dd1180c122fc3a8 F src/sqlite3ext.h 61b38c073d5e1e96a3d45271b257aef27d0d13da2bea5347692ae579475cd95e -F src/sqliteInt.h d7982229bd90ad5646e9250729125fb2f8a429de965c8825a8e378400e9d3c32 +F src/sqliteInt.h 11b9d47e9b9520b123bc75254da7a4e215463e811e62b89518fc5e9a192a0222 F src/sqliteLimit.h d7323ffea5208c6af2734574bae933ca8ed2ab728083caa117c9738581a31657 F src/status.c 4b8bc2a6905163a38b739854a35b826c737333fab5b1f8e03fa7eb9a4799c4c1 F src/table.c 0f141b58a16de7e2fbe81c308379e7279f4c6b50eb08efeec5892794a0ba30d1 @@ -633,7 +633,7 @@ F src/where.c a02138440d7230493b5e508664d629f3e1e7615737a5d83aac3a2955d3a654ff F src/whereInt.h 446e5e8018f83358ef917cf32d8e6a86dc8430113d0b17e720f1839d3faa44c4 F src/wherecode.c e57a8690311a75d06e723e8d379f9831de04aba300e07174d236e32a7f9c7a13 F src/whereexpr.c 2dc51263e1fb8d8723e97a077a9a137ab0534e59e4cb88b3195f65edbe43cc32 -F src/window.c edd6f5e25a1e8f2b6f5305b7f5f7da7bb35f07f0d432b255b1d4c2fcab4205aa +F src/window.c fdf01316f6cecf060378aa1713a29e527ab683823ba7d15b8978ec70165e8bdb F test/8_3_names.test ebbb5cd36741350040fd28b432ceadf495be25b2 F test/affinity2.test ce1aafc86e110685b324e9a763eab4f2a73f737842ec3b687bd965867de90627 F test/affinity3.test eecb0dabee4b7765a8465439d5e99429279ffba23ca74a7eae270a452799f9e7 @@ -1782,7 +1782,8 @@ F test/windowA.test 6d63dc1260daa17141a55007600581778523a8b420629f1282d2acfc36af F test/windowB.test 7a983ea1cc1cf72be7f378e4b32f6cb2d73014c5cd8b25aaee825164cd4269e5 F test/windowerr.tcl f5acd6fbc210d7b5546c0e879d157888455cd4a17a1d3f28f07c1c8a387019e0 F test/windowerr.test a8b752402109c15aa1c5efe1b93ccb0ce1ef84fa964ae1cd6684dd0b3cc1819b -F test/windowfault.test 72375ae71031eabf96bc88d0af128c8628a091ddc99b5a394e848b3df5fc17ad +F test/windowfault.test d543d46571b32d19f198cb04b6505747fabf3cc369970daae47074ee793612be +F test/windowpushd.test 5b9c114e8173c3addacf58a0fcd941437b14649f2033700184479a13f188ad00 F test/with1.test 780be387f01e290e768bdfd1827280f9e37ba37223eb4736aba386864fac5a94 F test/with2.test e0030e2f0267a910d6c0e4f46f2dfe941c1cc0d4f659ba69b3597728e7e8f1ab F test/with3.test 85e059bf4c2ef5626411ee59f399b4bb4b4a0f009bcb7db86f254e570ed11831 @@ -1906,7 +1907,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 b5a0778cc5a98a864bea72670f83262da940aceb91fa4cdf46ec097337a38a95 -R a0e8651539d2046a2eacfb9a26cd3050 -U drh -Z 9ff3dc4427ac90918959bed5bdbcba59 +P 64878124c160f790bc5861fd799ada03bd7db0c4426b8abc3b7ad1f7aa181168 4b089f70117bfb440eaefd830c05576be0cc624d9d6018c869270dc68e44513e +R 267c5ff70b9a1aed147827dba5df0c68 +T +closed 4b089f70117bfb440eaefd830c05576be0cc624d9d6018c869270dc68e44513e +U dan +Z f3731ba7b880bf6d7b3236243b9b4e61 diff --git a/manifest.uuid b/manifest.uuid index afadf1dc1b..c99b49c75f 100644 --- a/manifest.uuid +++ b/manifest.uuid @@ -1 +1 @@ -64878124c160f790bc5861fd799ada03bd7db0c4426b8abc3b7ad1f7aa181168 \ No newline at end of file +20689468100aed264877111367b42837ca19e63e717fed2ebd4b20b908f13178 \ No newline at end of file diff --git a/src/select.c b/src/select.c index 82e47a5840..b1a1ea507e 100644 --- a/src/select.c +++ b/src/select.c @@ -4489,6 +4489,35 @@ static int propagateConstants( return nChng; } +#if !defined(SQLITE_OMIT_SUBQUERY) || !defined(SQLITE_OMIT_VIEW) +# if !defined(SQLITE_OMIT_WINDOWFUNC) +/* +** This function is called to determine whether or not it is safe to +** push WHERE clause expression pExpr down to FROM clause sub-query +** pSubq, which contains at least one window function. Return 1 +** if it is safe and the expression should be pushed down, or 0 +** otherwise. +** +** It is only safe to push the expression down if it consists only +** of constants and copies of expressions that appear in the PARTITION +** BY clause of all window function used by the sub-query. It is safe +** to filter out entire partitions, but not rows within partitions, as +** this may change the results of the window functions. +** +** At the time this function is called it is guaranteed that +** +** * the sub-query uses only one distinct window frame, and +** * that the window frame has a PARTITION BY clase. +*/ +static int pushDownWindowCheck(Parse *pParse, Select *pSubq, Expr *pExpr){ + assert( pSubq->pWin->pPartition ); + assert( (pSubq->selFlags & SF_MultiPart)==0 ); + assert( pSubq->pPrior==0 ); + return sqlite3ExprIsConstantOrGroupBy(pParse, pExpr, pSubq->pWin->pPartition); +} +# endif /* SQLITE_OMIT_WINDOWFUNC */ +#endif /* !defined(SQLITE_OMIT_SUBQUERY) || !defined(SQLITE_OMIT_VIEW) */ + #if !defined(SQLITE_OMIT_SUBQUERY) || !defined(SQLITE_OMIT_VIEW) /* ** Make copies of relevant WHERE clause terms of the outer query into @@ -4536,9 +4565,20 @@ static int propagateConstants( ** But if the (b2=2) term were to be pushed down into the bb subquery, ** then the (1,1,NULL) row would be suppressed. ** -** (6) The inner query features one or more window-functions (since -** changes to the WHERE clause of the inner query could change the -** window over which window functions are calculated). +** (6) Window functions make things tricky as changes to the WHERE clause +** of the inner query could change the window over which window +** functions are calculated. Therefore, do not attempt the optimization +** if: +** +** (6a) The inner query uses multiple incompatible window partitions. +** +** (6b) The inner query is a compound and uses window-functions. +** +** (6c) The WHERE clause does not consist entirely of constants and +** copies of expressions found in the PARTITION BY clause of +** all window-functions used by the sub-query. It is safe to +** filter out entire partitions, as this does not change the +** window over which any window-function is calculated. ** ** (7) The inner query is a Common Table Expression (CTE) that should ** be materialized. (This restriction is implemented in the calling @@ -4556,13 +4596,17 @@ static int pushDownWhereTerms( ){ Expr *pNew; int nChng = 0; - Select *pSel; if( pWhere==0 ) return 0; - if( pSubq->selFlags & SF_Recursive ) return 0; /* restriction (2) */ + if( pSubq->selFlags & (SF_Recursive|SF_MultiPart) ) return 0; #ifndef SQLITE_OMIT_WINDOWFUNC - for(pSel=pSubq; pSel; pSel=pSel->pPrior){ - if( pSel->pWin ) return 0; /* restriction (6) */ + if( pSubq->pPrior ){ + Select *pSel; + for(pSel=pSubq; pSel; pSel=pSel->pPrior){ + if( pSel->pWin ) return 0; /* restriction (6b) */ + } + }else{ + if( pSubq->pWin && pSubq->pWin->pPartition==0 ) return 0; } #endif @@ -4609,6 +4653,14 @@ static int pushDownWhereTerms( x.isLeftJoin = 0; x.pEList = pSubq->pEList; pNew = substExpr(&x, pNew); +#ifndef SQLITE_OMIT_WINDOWFUNC + if( pSubq->pWin && 0==pushDownWindowCheck(pParse, pSubq, pNew) ){ + /* Restriction 6c has prevented push-down in this case */ + sqlite3ExprDelete(pParse->db, pNew); + nChng--; + break; + } +#endif if( pSubq->selFlags & SF_Aggregate ){ pSubq->pHaving = sqlite3ExprAnd(pParse, pSubq->pHaving, pNew); }else{ diff --git a/src/sqliteInt.h b/src/sqliteInt.h index c2db0f8b6e..1d5f0d2a87 100644 --- a/src/sqliteInt.h +++ b/src/sqliteInt.h @@ -3204,6 +3204,7 @@ struct Select { #define SF_NoopOrderBy 0x0400000 /* ORDER BY is ignored for this query */ #define SF_UpdateFrom 0x0800000 /* Statement is an UPDATE...FROM */ #define SF_PushDown 0x1000000 /* SELECT has be modified by push-down opt */ +#define SF_MultiPart 0x2000000 /* Has multiple incompatible PARTITIONs */ /* ** The results of a SELECT can be distributed in several ways, as defined diff --git a/src/window.c b/src/window.c index 88ff7d314d..09572ec033 100644 --- a/src/window.c +++ b/src/window.c @@ -1304,15 +1304,19 @@ void sqlite3WindowAttach(Parse *pParse, Expr *p, Window *pWin){ ** SELECT, or (b) the windows already linked use a compatible window frame. */ void sqlite3WindowLink(Select *pSel, Window *pWin){ - if( pSel!=0 - && (0==pSel->pWin || 0==sqlite3WindowCompare(0, pSel->pWin, pWin, 0)) - ){ - pWin->pNextWin = pSel->pWin; - if( pSel->pWin ){ - pSel->pWin->ppThis = &pWin->pNextWin; + if( pSel ){ + if( 0==pSel->pWin || 0==sqlite3WindowCompare(0, pSel->pWin, pWin, 0) ){ + pWin->pNextWin = pSel->pWin; + if( pSel->pWin ){ + pSel->pWin->ppThis = &pWin->pNextWin; + } + pSel->pWin = pWin; + pWin->ppThis = &pSel->pWin; + }else{ + if( sqlite3ExprListCompare(pWin->pPartition, pSel->pWin->pPartition,-1) ){ + pSel->selFlags |= SF_MultiPart; + } } - pSel->pWin = pWin; - pWin->ppThis = &pSel->pWin; } } diff --git a/test/windowfault.test b/test/windowfault.test index aea2340215..27c7742b30 100644 --- a/test/windowfault.test +++ b/test/windowfault.test @@ -246,6 +246,7 @@ do_faultsim_test 10 -faults oom* -prep { faultsim_test_result {0 {}} } +#------------------------------------------------------------------------- reset_db do_execsql_test 11.0 { DROP TABLE IF EXISTS t0; @@ -253,7 +254,7 @@ do_execsql_test 11.0 { INSERT INTO t0 VALUES(0); } {} -do_faultsim_test 11 -faults oom* -prep { +do_faultsim_test 11.1 -faults oom* -prep { } -body { execsql { SELECT * FROM t0 WHERE @@ -263,7 +264,7 @@ do_faultsim_test 11 -faults oom* -prep { faultsim_test_result {0 {}} } -do_faultsim_test 11 -faults oom* -prep { +do_faultsim_test 11.2 -faults oom* -prep { } -body { execsql { VALUES(false),(current_date collate binary) @@ -274,4 +275,21 @@ do_faultsim_test 11 -faults oom* -prep { faultsim_test_result {0 {}} } +#------------------------------------------------------------------------- +reset_db +do_execsql_test 12.0 { + CREATE TABLE t1(a, b, c); +} {} +do_faultsim_test 12 -faults oom* -prep { +} -body { + execsql { + WITH v(a, b, row_number) AS ( + SELECT a, b, row_number() OVER (PARTITION BY a ORDER BY b) FROM t1 + ) + SELECT * FROM v WHERE a=2 + } +} -test { + faultsim_test_result {0 {}} +} + finish_test diff --git a/test/windowpushd.test b/test/windowpushd.test new file mode 100644 index 0000000000..4462a0b4b4 --- /dev/null +++ b/test/windowpushd.test @@ -0,0 +1,237 @@ +# 2021 February 23 +# +# 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. +# +#*********************************************************************** +# This file implements regression tests for SQLite library. The +# focus of this file is testing the push-down optimization when +# WHERE constraints are pushed down into a sub-query that uses +# window functions. +# + +set testdir [file dirname $argv0] +source $testdir/tester.tcl +set testprefix windowpushd + +do_execsql_test 1.0 { + CREATE TABLE t1(id INTEGER PRIMARY KEY, grp_id); + CREATE INDEX i1 ON t1(grp_id); + CREATE VIEW lll AS SELECT + row_number() OVER (PARTITION BY grp_id), + grp_id, id + FROM t1 +} + +do_execsql_test 1.1 { + INSERT INTO t1 VALUES + (1, 2), (2, 3), (3, 3), (4, 1), (5, 1), + (6, 1), (7, 1), (8, 1), (9, 3), (10, 3), + (11, 2), (12, 3), (13, 3), (14, 2), (15, 1), + (16, 2), (17, 1), (18, 2), (19, 3), (20, 2) +} + +do_execsql_test 1.2 { + SELECT * FROM lll +} { + 1 1 4 2 1 5 3 1 6 4 1 7 5 1 8 6 1 15 7 1 17 + 1 2 1 2 2 11 3 2 14 4 2 16 5 2 18 6 2 20 + 1 3 2 2 3 3 3 3 9 4 3 10 5 3 12 6 3 13 7 3 19 +} + +do_execsql_test 1.3 { + SELECT * FROM lll WHERE grp_id=2 +} { + 1 2 1 2 2 11 3 2 14 4 2 16 5 2 18 6 2 20 +} + +do_eqp_test 1.4 { + SELECT * FROM lll WHERE grp_id=2 +} {SEARCH TABLE t1 USING COVERING INDEX i1 (grp_id=?)} + +#------------------------------------------------------------------------- +reset_db +do_execsql_test 2.0 { + CREATE TABLE t1(a, b, c, d); + INSERT INTO t1 VALUES('A', 'C', 1, 0.1); + INSERT INTO t1 VALUES('A', 'D', 2, 0.2); + INSERT INTO t1 VALUES('A', 'E', 3, 0.3); + INSERT INTO t1 VALUES('A', 'C', 4, 0.4); + INSERT INTO t1 VALUES('B', 'D', 5, 0.5); + INSERT INTO t1 VALUES('B', 'E', 6, 0.6); + INSERT INTO t1 VALUES('B', 'C', 7, 0.7); + INSERT INTO t1 VALUES('B', 'D', 8, 0.8); + INSERT INTO t1 VALUES('C', 'E', 9, 0.9); + INSERT INTO t1 VALUES('C', 'C', 10, 1.0); + INSERT INTO t1 VALUES('C', 'D', 11, 1.1); + INSERT INTO t1 VALUES('C', 'E', 12, 1.2); + + CREATE INDEX i1 ON t1(a); + CREATE INDEX i2 ON t1(b); + + CREATE VIEW v1 AS SELECT a, c, max(c) OVER (PARTITION BY a) FROM t1; + + CREATE VIEW v2 AS SELECT a, c, + max(c) OVER (PARTITION BY a), + row_number() OVER () + FROM t1; + + CREATE VIEW v3 AS SELECT b, d, + max(d) OVER (PARTITION BY b), + row_number() OVER (PARTITION BY b) + FROM t1; + + CREATE TABLE t2(x, y, z); + INSERT INTO t2 VALUES('W', 3, 1); + INSERT INTO t2 VALUES('W', 2, 2); + INSERT INTO t2 VALUES('X', 1, 4); + INSERT INTO t2 VALUES('X', 5, 7); + INSERT INTO t2 VALUES('Y', 1, 9); + INSERT INTO t2 VALUES('Y', 4, 2); + INSERT INTO t2 VALUES('Z', 3, 3); + INSERT INTO t2 VALUES('Z', 3, 4); +} + +foreach tn {0 1} { + optimization_control db push-down $tn + + do_execsql_test 2.$tn.1.1 { + SELECT * FROM v1; + } { + A 1 4 A 2 4 A 3 4 A 4 4 + B 5 8 B 6 8 B 7 8 B 8 8 + C 9 12 C 10 12 C 11 12 C 12 12 + } + + do_execsql_test 2.$tn.1.2 { + SELECT * FROM v1 WHERE a IN ('A', 'B'); + } { + A 1 4 A 2 4 A 3 4 A 4 4 + B 5 8 B 6 8 B 7 8 B 8 8 + } + + do_execsql_test 2.$tn.1.3 { + SELECT * FROM v1 WHERE a IS 'C' + } { + C 9 12 C 10 12 C 11 12 C 12 12 + } + + if {$tn==1} { + do_eqp_test 2.$tn.1.4 { + SELECT * FROM v1 WHERE a IN ('A', 'B'); + } {USING INDEX i1 (a=?)} + + do_eqp_test 2.$tn.1.5 { + SELECT * FROM v1 WHERE a = 'c' COLLATE nocase + } {USING INDEX i1} + } + + do_execsql_test 2.$tn.2.1 { + SELECT * FROM v2; + } { + A 1 4 1 A 2 4 2 A 3 4 3 A 4 4 4 + B 5 8 5 B 6 8 6 B 7 8 7 B 8 8 8 + C 9 12 9 C 10 12 10 C 11 12 11 C 12 12 12 + } + + do_execsql_test 2.$tn.2.2 { + SELECT * FROM v2 WHERE a = 'C'; + } { + C 9 12 9 C 10 12 10 C 11 12 11 C 12 12 12 + } + + do_execsql_test 2.$tn.3.1 { SELECT * FROM v3; } { + C 0.1 1.0 1 C 0.4 1.0 2 C 0.7 1.0 3 C 1.0 1.0 4 + D 0.2 1.1 1 D 0.5 1.1 2 D 0.8 1.1 3 D 1.1 1.1 4 + E 0.3 1.2 1 E 0.6 1.2 2 E 0.9 1.2 3 E 1.2 1.2 4 + } + + do_execsql_test 2.$tn.3.2 { SELECT * FROM v3 WHERE b<'E' } { + C 0.1 1.0 1 C 0.4 1.0 2 C 0.7 1.0 3 C 1.0 1.0 4 + D 0.2 1.1 1 D 0.5 1.1 2 D 0.8 1.1 3 D 1.1 1.1 4 + } + + if {$tn==1} { + do_eqp_test 2.$tn.3.3 { + SELECT * FROM v3 WHERE b='E' + } {SEARCH TABLE t1 USING INDEX i2 (b=?)} + do_eqp_test 2.$tn.3.4 { + SELECT * FROM v3 WHERE b>'C' + } {SEARCH TABLE t1 USING INDEX i2 (b>?)} + } + + do_execsql_test 2.$tn.3.5 { SELECT * FROM v3 WHERE d<0.55; } { + C 0.1 1.0 1 C 0.4 1.0 2 + D 0.2 1.1 1 D 0.5 1.1 2 + E 0.3 1.2 1 + } + if {$tn==1} { + do_eqp_test 2.$tn.3.6 { + SELECT * FROM v3 WHERE d<0.55 + } {SCAN TABLE t1 USING INDEX i2} + } + + do_execsql_test 2.$tn.4.1 { + SELECT * FROM ( + SELECT x, sum(y) AS s, max(z) AS m + FROM t2 GROUP BY x + ) + } { + W 5 2 + X 6 7 + Y 5 9 + Z 6 4 + } + + do_execsql_test 2.$tn.4.1 { + SELECT * FROM ( + SELECT x, sum(y) AS s, max(z) AS m, + max( max(z) ) OVER (PARTITION BY sum(y) + ROWS BETWEEN UNBOUNDED PRECEDING AND UNBOUNDED FOLLOWING + ) + FROM t2 GROUP BY x + ) + } { + W 5 2 9 + Y 5 9 9 + X 6 7 7 + Z 6 4 7 + } + + do_execsql_test 2.$tn.4.2 { + SELECT * FROM ( + SELECT x, sum(y) AS s, max(z) AS m, + max( max(z) ) OVER (PARTITION BY sum(y) + ROWS BETWEEN UNBOUNDED PRECEDING AND UNBOUNDED FOLLOWING + ) + FROM t2 GROUP BY x + ) WHERE s=6 + } { + X 6 7 7 + Z 6 4 7 + } + + do_execsql_test 2.$tn.4.3 { + SELECT * FROM ( + SELECT x, sum(y) AS s, max(z) AS m, + max( max(z) ) OVER (PARTITION BY sum(y) + ROWS BETWEEN UNBOUNDED PRECEDING AND UNBOUNDED FOLLOWING + ) + FROM t2 GROUP BY x + ) WHERE s<6 + } { + W 5 2 9 + Y 5 9 9 + } + +} + + + + +finish_test +