If a subquery is materialized due to an ORDER BY and that ordering is useful

in helping to satisfy the ORDER BY or GROUP BY in the order query without
doing an extra sort, then omit the extra sort.

FossilOrigin-Name: 2fbb4dc2327ee435cb2b7a4adcddf5a9cee6dff7de96e2ecb761166427b5ddea
This commit is contained in:
drh 2024-08-15 23:38:52 +00:00
parent 7c5a829025
commit 235b5d0ac5
10 changed files with 203 additions and 20 deletions

View File

@ -1,5 +1,5 @@
C Improved\shelp\smessage\sfor\s--disable-tcl\son\sthe\sconfigure\sscript.
D 2024-08-15T15:31:46.143
C If\sa\ssubquery\sis\smaterialized\sdue\sto\san\sORDER\sBY\sand\sthat\sordering\sis\suseful\nin\shelping\sto\ssatisfy\sthe\sORDER\sBY\sor\sGROUP\sBY\sin\sthe\sorder\squery\swithout\ndoing\san\sextra\ssort,\sthen\somit\sthe\sextra\ssort.
D 2024-08-15T23:38:52.210
F .fossil-settings/empty-dirs dbb81e8fc0401ac46a1491ab34a7f2c7c0452f2f06b54ebb845d024ca8283ef1
F .fossil-settings/ignore-glob 35175cdfcf539b2318cb04a9901442804be81cd677d8b889fcc9149c21f239ea
F LICENSE.md df5091916dbb40e6e9686186587125e1b2ff51f022cc334e886c19a0e9982724
@ -765,13 +765,13 @@ F src/shell.c.in 94571558b0fb28c37a5cf6dbd6ea27285341023a28a8cb5795cd2768fab6770
F src/sqlite.h.in 1ad9110150773c38ebababbad11b5cb361bcd3997676dec1c91ac5e0416a7b86
F src/sqlite3.rc 5121c9e10c3964d5755191c80dd1180c122fc3a8
F src/sqlite3ext.h 3f046c04ea3595d6bfda99b781926b17e672fd6d27da2ba6d8d8fc39981dcb54
F src/sqliteInt.h e3f3b3d80a666a7c5c85b4db102d41ca831c5624f0b3001814479d376f00c19d
F src/sqliteInt.h 128b9004698cc79993d5369d7d1763deaf8bbf26e5e8931ec540707e5a7238df
F src/sqliteLimit.h 6878ab64bdeb8c24a1d762d45635e34b96da21132179023338c93f820eee6728
F src/status.c cb11f8589a6912af2da3bb1ec509a94dd8ef27df4d4c1a97e0bcf2309ece972b
F src/table.c 0f141b58a16de7e2fbe81c308379e7279f4c6b50eb08efeec5892794a0ba30d1
F src/tclsqlite.c c6888598f08dee3d9112a38ef42c8f5c89ca7f3190f4694744d0b84250f4bf8c
F src/tclsqlite.h c6af51f31a2b2172d674608763a4b98fdf5cd587e4025053e546fb8077757262
F src/test1.c be8cc208c0d50b3a7e570049e55f25ae40c1dfec8165b7ce12c2c8ed9f5b3030
F src/test1.c 3f18399557d954bc85f4564aec8ea1777d2161a81d98a3ff6c9e9046bf3554c1
F src/test2.c 7ebc518e6735939d8979273a6f7b1d9b5702babf059f6ad62499f7f60a9eb9a3
F src/test3.c e7573aa0f78ee4e070a4bc8c3493941c1aa64d5c66d4825c74c0f055451f432b
F src/test4.c 13e57ae7ec7a959ee180970aef09deed141252fe9bb07c61054f0dfa4f1dfd5d
@ -846,8 +846,8 @@ F src/vxworks.h d2988f4e5a61a4dfe82c6524dd3d6e4f2ce3cdb9
F src/wal.c 887fc4ca3f020ebb2e376f222069570834ac63bf50111ef0cbf3ae417048ed89
F src/wal.h ba252daaa94f889f4b2c17c027e823d9be47ce39da1d3799886bbd51f0490452
F src/walker.c 7c7ea0115345851c3da4e04e2e239a29983b61fb5b038b94eede6aba462640e2
F src/where.c 3556ef464ac78f4730f40c085aa0b6729ffe44306c0daaaffe9370c981a66d1d
F src/whereInt.h 002adc3aa2cc10733b9b27958fdbe893987cd989fab25a9853941c1f9b9b0a65
F src/where.c c59dffd249e5daa335bc43c2b87ffacc25dce995e3600a2b7bcdbcc55a68c985
F src/whereInt.h 6444b888ce395cb80511284b8a73b63472d34247fcb1b125ee06a54fa6ae878e
F src/wherecode.c c9cac0b0b8e809c5e7e79d7796918907fb685ad99be2aaa9737f9787aa47349c
F src/whereexpr.c 7d0d34b42b9edfd8e8ca66beb3a6ef63fe211c001af54caf2ccbcd989b783290
F src/window.c 1e40ffc509bae21e466f6106382d238e91eb73edd4ba10e66ca4fd7af2b96896
@ -1113,7 +1113,7 @@ F test/enc.test 9a7be5479da985381d740b15f432800f65e2c87029ee57a318f42cb2eb43763a
F test/enc2.test 848bf05f15b011719f478dddb7b5e9aea35e39e457493cba4c4eef75d849a5ec
F test/enc3.test 55ef64416d72975c66167310a51dc9fc544ba3ae4858b8d5ab22f4cb6500b087
F test/enc4.test c8f1ce3618508fd0909945beb8b8831feef2c020
F test/eqp.test 815418b69f6be3a27037b1736c54699c72cc3e2e6b0bc878c01464d1dcec65fe
F test/eqp.test 82f221e8cd588434d7f3bba9a0f4c78cbe7a541615a41632e12f50608bfb4a99
F test/eqp2.test 6e8996148de88f0e7670491e92e712a2920a369b4406f21a27c3c9b6a46b68dd
F test/errmsg.test eae9f091eb39ce7e20305de45d8e5d115b68fa856fba4ea6757b6ca3705ff7f9
F test/eval.test 73969a2d43a511bf44080c44485a8c4d796b6a4f038d19e491867081155692c0
@ -1632,7 +1632,7 @@ F test/shortread1.test bb591ef20f0fd9ed26d0d12e80eee6d7ac8897a3
F test/show_speedtest1_rtree.tcl 32e6c5f073d7426148a6936a0408f4b5b169aba5
F test/shrink.test 2668e607dcdfa19c52828c09b69685b38da793856582ae31debf79d90c7bbbdc
F test/sidedelete.test f0ad71abe6233e3b153100f3b8d679b19a488329
F test/skipscan1.test e03ba5b977da6fd71662a4b0a668f04053bda4b187ff3214db7533e28c732279
F test/skipscan1.test 9cbbb6575517b15292bd87ee85b853bbd3cd4b4735d69b0f083020cec16ff304
F test/skipscan2.test b032ed3e0ba5caa4df6c43ef22c31566aac67783bc031869155989a7ccdb5bd5
F test/skipscan3.test ec5bab3f81c7038b43450e7b3062e04a198bdbb5
F test/skipscan5.test 0672103fd2c8f96bd114133f356192b35ece45c794fe3677e1d9e5e3104a608e
@ -2067,13 +2067,13 @@ F test/windowE.test 6ba0c8048e4cc02b942e56640f8fcd50fd7ca72c876656c40f6baf42e316
F test/windowerr.tcl f5acd6fbc210d7b5546c0e879d157888455cd4a17a1d3f28f07c1c8a387019e0
F test/windowerr.test a8b752402109c15aa1c5efe1b93ccb0ce1ef84fa964ae1cd6684dd0b3cc1819b
F test/windowfault.test 15094c1529424e62f798bc679e3fe9dfab6e8ba2f7dfe8c923b6248c31660a7c
F test/windowpushd.test d8895d08870b7226f7693665bd292eb177e62ca06799184957b3ca7dc03067df
F test/windowpushd.test c420e2265f0e09a0e798d0513a660d71b51602088d81b3dbd038918ee1339dcc
F test/with1.test b93833890e5d2a368e78747f124503a0159aa029b98e9ed4795ebf630b2efd3d
F test/with2.test a1df41b987198383b9b70bf5e5fda390582e46398653858dbc6ceb24253b28df
F test/with3.test e30369ea27aa27eb1bda4c5e510c8a9f782c8afd2ab99d1a02b8a7f25a5d3e65
F test/with4.test 257be66c0c67fee1defbbac0f685c3465e2cad037f21ce65f23f86084f198205
F test/with5.test 6248213c41fab36290b5b73aa3f937309dfba337004d9d8434c3fabc8c7d4be8
F test/with6.test e097a03e5c898a8cd8f3a2d6a994ec510ea4376b5d484c2b669a41001e7758c8
F test/with6.test 9ff3503c3ff7cd459dc4852a02aaefa998dccace53f4142a0eb726174ad5984a
F test/withM.test 693b61765f2b387b5e3e24a4536e2e82de15ff64
F test/without_rowid1.test a5210b8770dc4736bca4e74bc96588f43025ad03ad6a80f885afd36d9890e217
F test/without_rowid2.test af260339f79d13cb220288b67cd287fbcf81ad99
@ -2204,8 +2204,11 @@ F vsixtest/vsixtest.tcl 6195aba1f12a5e10efc2b8c0009532167be5e301abe5b31385638080
F vsixtest/vsixtest.vcxproj.data 2ed517e100c66dc455b492e1a33350c1b20fbcdc
F vsixtest/vsixtest.vcxproj.filters 37e51ffedcdb064aad6ff33b6148725226cd608e
F vsixtest/vsixtest_TemporaryKey.pfx e5b1b036facdb453873e7084e1cae9102ccc67a0
P de927016aadd7ee55d947134e3540907a3ea5ab4015034c5d088e3a84905d98a
R fa965b3cf027827ab805def1d12c22e4
P 96e6cfb211f7f1aab50f997f4bc61dfb9701beb720c59bc413a4285c1ae5e20d
R cc9a8ceafd2a9a7a7cbd542af1820055
T *branch * order-by-subquery
T *sym-order-by-subquery *
T -sym-trunk *
U drh
Z a05ca4fe471b9ed0243c4a5725784485
Z 66dcbf2773ae39411ce78a1d9346e7ac
# Remove this line to create a well-formed Fossil manifest.

View File

@ -1 +1 @@
96e6cfb211f7f1aab50f997f4bc61dfb9701beb720c59bc413a4285c1ae5e20d
2fbb4dc2327ee435cb2b7a4adcddf5a9cee6dff7de96e2ecb761166427b5ddea

View File

@ -1927,6 +1927,7 @@ struct sqlite3 {
#define SQLITE_Coroutines 0x02000000 /* Co-routines for subqueries */
#define SQLITE_NullUnusedCols 0x04000000 /* NULL unused columns in subqueries */
#define SQLITE_OnePass 0x08000000 /* Single-pass DELETE and UPDATE */
#define SQLITE_OrderBySubq 0x10000000 /* ORDER BY in subquery helps outer */
#define SQLITE_AllOpts 0xffffffff /* All optimizations */
/*

View File

@ -8100,6 +8100,7 @@ static int SQLITE_TCLAPI optimization_control(
{ "distinct-opt", SQLITE_DistinctOpt },
{ "cover-idx-scan", SQLITE_CoverIdxScan },
{ "order-by-idx-join", SQLITE_OrderByIdxJoin },
{ "order-by-subquery", SQLITE_OrderBySubq },
{ "transitive", SQLITE_Transitive },
{ "omit-noop-join", SQLITE_OmitNoopJoin },
{ "stat4", SQLITE_Stat4 },

View File

@ -4010,6 +4010,10 @@ static int whereLoopAddBtree(
#endif
ApplyCostMultiplier(pNew->rRun, pTab->costMult);
whereLoopOutputAdjust(pWC, pNew, rSize);
if( pSrc->pSelect ){
if( pSrc->fg.viaCoroutine ) pNew->wsFlags |= WHERE_COROUTINE;
pNew->u.btree.pOrderBy = pSrc->pSelect->pOrderBy;
}
rc = whereLoopInsert(pBuilder, pNew);
pNew->nOut = rSize;
if( rc ) break;
@ -4843,6 +4847,69 @@ static int whereLoopAddAll(WhereLoopBuilder *pBuilder){
return rc;
}
/*
** WhereLoop pLoop, which the iLoop-th term of the nested loop, is really
** a subquery or CTE that has an ORDER BY clause. See if any of the terms
** in the subquery ORDER BY clause will satisfy pOrderBy from the outer
** query. Mark off all satisfied terms (by setting bits in *pOBSat) and
** return TRUE if they do. If not, return false.
**
** Example:
**
** CREATE TABLE t1(a,b,c, PRIMARY KEY(a,b));
** CREATE TABLE t2(x,y);
** WITH t3(p,q) AS MATERIALIZED (SELECT x+y, x-y FROM t2 ORDER BY x+y)
** SELECT * FROM t3 JOIN t1 ON a=q ORDER BY p, b;
**
** The CTE named "t3" comes out in the natural order of "p", so the first
** first them of "ORDER BY p,b" is satisfied by a sequential scan of "t3".
**
*/
static SQLITE_NOINLINE int wherePathMatchSubqueryOB(
WhereLoop *pLoop, /* The nested loop term that is a subquery */
int iLoop, /* Which level of the nested loop. 0==outermost */
int iCur, /* Cursor used by the this loop */
int wctrlFlags, /* Flags determining sort behavior */
ExprList *pOrderBy, /* The ORDER BY clause on the whole query */
Bitmask *pRevMask, /* When loops need to go in reverse order */
Bitmask *pOBSat /* Which terms of pOrderBy are satisfied so far */
){
int i, j;
u8 rev = 0;
u8 revIdx = 0;
Expr *pOBExpr;
ExprList *pSubOB = pLoop->u.btree.pOrderBy;
assert( pSubOB!=0 );
for(i=0; (MASKBIT(i) & *pOBSat)!=0; i++){}
for(j=0; j<pSubOB->nExpr && i<pOrderBy->nExpr; j++, i++){
if( pSubOB->a[j].u.x.iOrderByCol==0 ) break;
pOBExpr = sqlite3ExprSkipCollateAndLikely(pOrderBy->a[j].pExpr);
if( pOBExpr->op!=TK_COLUMN && pOBExpr->op!=TK_AGG_COLUMN ) break;
if( pOBExpr->iTable!=iCur ) break;
if( pOBExpr->iColumn!=pSubOB->a[j].u.x.iOrderByCol-1 ) break;
if( pSubOB->a[j].fg.sortFlags & KEYINFO_ORDER_BIGNULL ) break;
revIdx = pSubOB->a[j].fg.sortFlags & KEYINFO_ORDER_DESC;
if( wctrlFlags & WHERE_GROUPBY ){
/* Sort order does not matter for GROUP BY */
}else if( j>0 ){
if( (rev ^ revIdx) != (pOrderBy->a[i].fg.sortFlags&KEYINFO_ORDER_DESC) ){
break;
}
}else{
rev = revIdx ^ (pOrderBy->a[i].fg.sortFlags & KEYINFO_ORDER_DESC);
if( rev ){
if( (pLoop->wsFlags & WHERE_COROUTINE)!=0 ){
/* Cannot run a co-routine in reverse order */
break;
}
*pRevMask |= MASKBIT(iLoop);
}
}
*pOBSat |= MASKBIT(i);
}
return j>0;
}
/*
** Examine a WherePath (with the addition of the extra WhereLoop of the 6th
** parameters) to see if it outputs rows in the requested ORDER BY
@ -4988,9 +5055,17 @@ static i8 wherePathSatisfiesOrderBy(
if( (pLoop->wsFlags & WHERE_ONEROW)==0 ){
if( pLoop->wsFlags & WHERE_IPK ){
if( pLoop->u.btree.pOrderBy
&& OptimizationEnabled(db, SQLITE_OrderBySubq)
&& wherePathMatchSubqueryOB(pLoop,iLoop,iCur,wctrlFlags,
pOrderBy,pRevMask, &obSat)
){
nColumn = 0;
}else{
nColumn = 1;
}
pIndex = 0;
nKeyCol = 0;
nColumn = 1;
}else if( (pIndex = pLoop->u.btree.pIndex)==0 || pIndex->bUnordered ){
return 0;
}else{
@ -5085,7 +5160,7 @@ static i8 wherePathSatisfiesOrderBy(
}
/* Find the ORDER BY term that corresponds to the j-th column
** of the index and mark that ORDER BY term off
** of the index and mark that ORDER BY term having been satisfied.
*/
isMatch = 0;
for(i=0; bOnce && i<nOrderBy; i++){

View File

@ -143,6 +143,7 @@ struct WhereLoop {
u16 nTop; /* Size of TOP vector */
u16 nDistinctCol; /* Index columns used to sort for DISTINCT */
Index *pIndex; /* Index used, or NULL */
ExprList *pOrderBy; /* ORDER BY clause if this is really a subquery */
} btree;
struct { /* Information for virtual tables */
int idxNum; /* Index number */
@ -636,7 +637,8 @@ void sqlite3WhereTabFuncArgs(Parse*, SrcItem*, WhereClause*);
#define WHERE_BLOOMFILTER 0x00400000 /* Consider using a Bloom-filter */
#define WHERE_SELFCULL 0x00800000 /* nOut reduced by extra WHERE terms */
#define WHERE_OMIT_OFFSET 0x01000000 /* Set offset counter to zero */
/* 0x02000000 -- available for reuse */
#define WHERE_COROUTINE 0x02000000 /* Implemented by co-routine.
** NB: False-negatives are possible */
#define WHERE_EXPRIDX 0x04000000 /* Uses an index-on-expressions */
#endif /* !defined(SQLITE_WHEREINT_H) */

View File

@ -288,6 +288,7 @@ det 3.2.1 {
|--SCAN (subquery-xxxxxx)
`--USE TEMP B-TREE FOR ORDER BY
}
det 3.2.2 {
SELECT * FROM
(SELECT * FROM t1 ORDER BY x LIMIT 10) AS x1,
@ -305,6 +306,16 @@ det 3.2.2 {
`--USE TEMP B-TREE FOR ORDER BY
}
det 3.2.3 {
SELECT * FROM (SELECT * FROM t1 ORDER BY x LIMIT 10) ORDER BY x LIMIT 5
} {
QUERY PLAN
|--CO-ROUTINE (subquery-xxxxxx)
| |--SCAN t1
| `--USE TEMP B-TREE FOR ORDER BY
`--SCAN (subquery-xxxxxx)
}
det 3.3.1 {
SELECT * FROM t1 WHERE y IN (SELECT y FROM t2)
} {
@ -807,6 +818,7 @@ do_execsql_test 9.0 {
CREATE INDEX event_i1 ON event(mtime);
CREATE TABLE private(rid INTEGER PRIMARY KEY);
}
optimization_control db order-by-subquery off
do_eqp_test 9.1 {
WITH thread(age,duration,cnt,root,last) AS (
SELECT
@ -847,5 +859,46 @@ do_eqp_test 9.1 {
|--SEARCH event USING INTEGER PRIMARY KEY (rowid=?)
`--USE TEMP B-TREE FOR ORDER BY
}
optimization_control db all on
db cache flush
do_eqp_test 9.2 {
WITH thread(age,duration,cnt,root,last) AS (
SELECT
julianday('now') - max(fmtime) AS age,
max(fmtime) - min(fmtime) AS duration,
sum(fprev IS NULL) AS msg_count,
froot,
(SELECT fpid FROM forumpost
WHERE froot=x.froot
AND fpid NOT IN private
ORDER BY fmtime DESC LIMIT 1)
FROM forumpost AS x
WHERE fpid NOT IN private --- Ensure this table mentioned in EQP output!
GROUP BY froot
ORDER BY 1 LIMIT 26 OFFSET 5
)
SELECT
thread.age,
thread.duration,
thread.cnt,
blob.uuid,
substr(event.comment,instr(event.comment,':')+1)
FROM thread, blob, event
WHERE blob.rid=thread.last
AND event.objid=thread.last
ORDER BY 1;
} {
QUERY PLAN
|--CO-ROUTINE thread
| |--SCAN x USING INDEX forumthread
| |--USING ROWID SEARCH ON TABLE private FOR IN-OPERATOR
| |--CORRELATED SCALAR SUBQUERY xxxxxx
| | |--SEARCH forumpost USING COVERING INDEX forumthread (froot=?)
| | `--USING ROWID SEARCH ON TABLE private FOR IN-OPERATOR
| `--USE TEMP B-TREE FOR ORDER BY
|--SCAN thread
|--SEARCH blob USING INTEGER PRIMARY KEY (rowid=?)
`--SEARCH event USING INTEGER PRIMARY KEY (rowid=?)
}
finish_test

View File

@ -337,12 +337,12 @@ do_execsql_test skipscan1-9.2 {
} {/USING INDEX t9a_ab .ANY.a. AND b=./}
optimization_control db skip-scan 0
optimization_control db skip-scan off
do_execsql_test skipscan1-9.3 {
EXPLAIN QUERY PLAN
SELECT * FROM t9a WHERE b IN (SELECT x FROM t9b WHERE y!=5);
} {/{SCAN t9a}/}
optimization_control db skip-scan 1
optimization_control db all on
do_execsql_test skipscan1-2.1 {
CREATE TABLE t6(a TEXT, b INT, c INT, d INT);

View File

@ -97,7 +97,11 @@ do_execsql_test 2.0 {
}
foreach tn {0 1} {
optimization_control db push-down $tn
if {$tn} {
optimization_control db all on
} else {
optimization_control db push-down off
}
do_execsql_test 2.$tn.1.1 {
SELECT * FROM v1;

View File

@ -350,6 +350,50 @@ do_eqp_test 400 {
FROM (SELECT f.*, exp(b) - 1 AS nFin, exp(a* (-1) + b) - 1 AS nPrev
FROM fit f JOIN init i on i.country = f.country AND f.date <= date(i.fin,'-3 days'))
WHERE nPrev > 0 AND nFin > 0;
} {
QUERY PLAN
|--MATERIALIZE sums
| |--MATERIALIZE src
| | |--MATERIALIZE init
| | | `--SCAN raw USING INDEX sqlite_autoindex_raw_1
| | |--SCAN i
| | |--SEARCH raw USING COVERING INDEX sqlite_autoindex_raw_1 (country=? AND date>?)
| | `--USE TEMP B-TREE FOR ORDER BY
| |--SCAN src
| `--SEARCH raw USING INDEX sqlite_autoindex_raw_1 (country=? AND date>? AND date<?)
|--SCAN sums
|--BLOOM FILTER ON sums (country=? AND date=?)
|--SEARCH sums USING AUTOMATIC COVERING INDEX (country=? AND date=?)
|--BLOOM FILTER ON sums (country=? AND date=?)
|--SEARCH sums USING AUTOMATIC COVERING INDEX (country=? AND date=?)
|--BLOOM FILTER ON sums (country=? AND date=?)
|--SEARCH sums USING AUTOMATIC COVERING INDEX (country=? AND date=?)
|--BLOOM FILTER ON i (country=?)
`--SEARCH i USING AUTOMATIC COVERING INDEX (country=?)
}
optimization_control db order-by-subquery off
db cache flush
do_eqp_test 410 {
with recursive
init(country, date, fin) AS (SELECT country, min(date), max(date) FROM raw WHERE total > 0 GROUP BY country),
src(country, date) AS (SELECT raw.country, raw.date
FROM raw JOIN init i on raw.country = i.country AND raw.date > i.date
ORDER BY raw.country, raw.date),
vals(country, date, x, y) AS (SELECT src.country, src.date, julianday(raw.date) - julianday(src.date), log(delta+1)
FROM src JOIN raw on raw.country = src.country AND raw.date > date(src.date,'-7 days') AND raw.date <= src.date AND delta >= 0),
sums(country, date, x2, x, n, xy, y) AS (SELECT country, date, sum(x*x*1.0), sum(x*1.0), sum(1.0), sum(x*y*1.0), sum(y*1.0) FROM vals GROUP BY 1, 2),
mult(country, date, m) AS (SELECT country, date, 1.0/(x2 * n - x * x) FROM sums),
inv(country, date, a,b,c,d) AS (SELECT mult.country, mult.date, n * m, -x * m, -x * m, x2 * m
FROM mult JOIN sums on sums.country=mult.country AND mult.date=sums.date),
fit(country, date, a, b) AS (SELECT inv.country, inv.date, a * xy + b * y, c * xy + d * y
FROM inv
JOIN mult on mult.country = inv.country AND mult.date = inv.date
JOIN sums on sums.country = mult.country AND sums.date = mult.date
)
SELECT *, nFin/nPrev - 1 AS growth, log(2)/log(nFin/nPrev) AS doubling
FROM (SELECT f.*, exp(b) - 1 AS nFin, exp(a* (-1) + b) - 1 AS nPrev
FROM fit f JOIN init i on i.country = f.country AND f.date <= date(i.fin,'-3 days'))
WHERE nPrev > 0 AND nFin > 0;
} {
QUERY PLAN
|--MATERIALIZE sums