3 # The author disclaims copyright to this source code. In place of
4 # a legal notice, here is a blessing:
6 # May you do good and not evil.
7 # May you find forgiveness for yourself and forgive others.
8 # May you share freely, never taking more than you give.
10 #***********************************************************************
11 # This file implements regression tests for SQLite library. The
12 # focus of this file is the MATERIALIZED hint to common table expressions
15 set testdir [file dirname $argv0]
16 source $testdir/tester.tcl
17 set ::testprefix with6
25 WITH c(x) AS (VALUES(0),(1))
26 SELECT c1.x||c2.x||c3.x FROM c c1, c c2, c c3;
27 } {000 001 010 011 100 101 110 111}
29 WITH c(x) AS (VALUES(0),(1))
30 SELECT c1.x||c2.x||c3.x FROM c c1, c c2, c c3;
34 | `--SCAN 2 CONSTANT ROWS
41 WITH c(x) AS MATERIALIZED (VALUES(0),(1))
42 SELECT c1.x||c2.x||c3.x FROM c c1, c c2, c c3;
43 } {000 001 010 011 100 101 110 111}
45 WITH c(x) AS MATERIALIZED (VALUES(0),(1))
46 SELECT c1.x||c2.x||c3.x FROM c c1, c c2, c c3;
50 | `--SCAN 2 CONSTANT ROWS
56 # Even though the CTE is not materialized, the self-join optimization
57 # kicks in and does the materialization for us.
60 WITH c(x) AS NOT MATERIALIZED (VALUES(0),(1))
61 SELECT c1.x||c2.x||c3.x FROM c c1, c c2, c c3;
62 } {000 001 010 011 100 101 110 111}
64 WITH c(x) AS NOT MATERIALIZED (VALUES(0),(1))
65 SELECT c1.x||c2.x||c3.x FROM c c1, c c2, c c3;
69 | `--SCAN 2 CONSTANT ROWS
76 WITH c(x) AS NOT MATERIALIZED (VALUES(0),(1))
77 SELECT c1.x||c2.x||c3.x
78 FROM (SELECT x FROM c LIMIT 5) AS c1,
79 (SELECT x FROM c LIMIT 5) AS c2,
80 (SELECT x FROM c LIMIT 5) AS c3;
81 } {000 001 010 011 100 101 110 111}
83 WITH c(x) AS NOT MATERIALIZED (VALUES(0),(1))
84 SELECT c1.x||c2.x||c3.x
85 FROM (SELECT x FROM c LIMIT 5) AS c1,
86 (SELECT x FROM c LIMIT 5) AS c2,
87 (SELECT x FROM c LIMIT 5) AS c3;
92 | | `--SCAN 2 CONSTANT ROWS
96 | | `--SCAN 2 CONSTANT ROWS
100 | | `--SCAN 2 CONSTANT ROWS
107 # The (SELECT x FROM c LIMIT N) subqueries get materialized once each.
108 # Show multiple materializations are shown. But there is only one
109 # materialization for c, shown by the "SCAN 2 CONSTANT ROWS" line.
111 do_execsql_test 140 {
112 WITH c(x) AS MATERIALIZED (VALUES(0),(1))
113 SELECT c1.x||c2.x||c3.x
114 FROM (SELECT x FROM c LIMIT 5) AS c1,
115 (SELECT x FROM c LIMIT 6) AS c2,
116 (SELECT x FROM c LIMIT 7) AS c3;
117 } {000 001 010 011 100 101 110 111}
119 WITH c(x) AS MATERIALIZED (VALUES(0),(1))
120 SELECT c1.x||c2.x||c3.x
121 FROM (SELECT x FROM c LIMIT 5) AS c1,
122 (SELECT x FROM c LIMIT 6) AS c2,
123 (SELECT x FROM c LIMIT 7) AS c3;
128 | | `--SCAN 2 CONSTANT ROWS
139 do_execsql_test 150 {
140 WITH c(x) AS (VALUES(0),(1))
141 SELECT c1.x||c2.x||c3.x
142 FROM (SELECT x FROM c LIMIT 5) AS c1,
143 (SELECT x FROM c LIMIT 6) AS c2,
144 (SELECT x FROM c LIMIT 7) AS c3;
145 } {000 001 010 011 100 101 110 111}
147 WITH c(x) AS (VALUES(0),(1))
148 SELECT c1.x||c2.x||c3.x
149 FROM (SELECT x FROM c LIMIT 5) AS c1,
150 (SELECT x FROM c LIMIT 6) AS c2,
151 (SELECT x FROM c LIMIT 7) AS c3;
156 | | `--SCAN 2 CONSTANT ROWS
167 do_execsql_test 160 {
168 WITH c(x) AS (VALUES(0),(1))
169 SELECT c2.x + 100*(SELECT sum(x+1) FROM c WHERE c.x<=c2.x)
170 FROM c AS c2 WHERE c2.x<10;
173 WITH c(x) AS (VALUES(0),(1))
174 SELECT c2.x + 100*(SELECT sum(x+1) FROM c WHERE c.x<=c2.x)
175 FROM c AS c2 WHERE c2.x<10;
179 | `--SCAN 2 CONSTANT ROWS
181 `--CORRELATED SCALAR SUBQUERY xxxxxx
185 do_execsql_test 170 {
186 WITH c(x) AS NOT MATERIALIZED (VALUES(0),(1))
187 SELECT c2.x + 100*(SELECT sum(x+1) FROM c WHERE c.x<=c2.x)
188 FROM c AS c2 WHERE c2.x<10;
191 WITH c(x) AS NOT MATERIALIZED (VALUES(0),(1))
192 SELECT c2.x + 100*(SELECT sum(x+1) FROM c WHERE c.x<=c2.x)
193 FROM c AS c2 WHERE c2.x<10;
197 | `--SCAN 2 CONSTANT ROWS
199 `--CORRELATED SCALAR SUBQUERY xxxxxx
201 | `--SCAN 2 CONSTANT ROWS
206 do_execsql_test 200 {
208 INSERT INTO t1(x) VALUES(4);
210 WITH c(z) AS (VALUES(4),(5),(6))
211 SELECT c1.z+c2.z*100+t1.x*10000
213 (SELECT z FROM c LIMIT 5) AS c1,
214 (SELECT z FROM c LIMIT 5) AS c2;
215 SELECT y FROM t2 ORDER BY y;
216 } {40404 40405 40406 40504 40505 40506 40604 40605 40606}
217 do_execsql_test 210 {
220 WITH c(z) AS NOT MATERIALIZED (VALUES(4),(5),(6))
221 SELECT c1.z+c2.z*100+t1.x*10000
223 (SELECT z FROM c LIMIT 5) AS c1,
224 (SELECT z FROM c LIMIT 5) AS c2;
225 SELECT y FROM t2 ORDER BY y;
226 } {40404 40405 40406 40504 40505 40506 40604 40605 40606}
228 SELECT y FROM t2 ORDER BY y;
233 | | `--SCAN 3 CONSTANT ROWS
237 | | `--SCAN 3 CONSTANT ROWS
242 `--USE TEMP B-TREE FOR ORDER BY
244 do_execsql_test 220 {
247 WITH c(z) AS MATERIALIZED (VALUES(4),(5),(6))
248 SELECT c1.z+c2.z*100+t1.x*10000
250 (SELECT z FROM c LIMIT 5) AS c1,
251 (SELECT z FROM c LIMIT 5) AS c2;
252 SELECT y FROM t2 ORDER BY y;
253 } {40404 40405 40406 40504 40505 40506 40604 40605 40606}
255 # 2022-04-22: Do not allow flattening of a MATERIALIZED CTE into
260 do_execsql_test 300 {
261 CREATE TABLE t2(a INT,b INT,d INT); INSERT INTO t2 VALUES(4,5,6),(7,8,9);
262 CREATE TABLE t3(a INT,b INT,e INT); INSERT INTO t3 VALUES(3,3,3),(8,8,8);
264 do_execsql_test 310 {
265 WITH t23 AS MATERIALIZED (SELECT * FROM t2 FULL JOIN t3 USING(b))
273 WITH t23 AS MATERIALIZED (SELECT * FROM t2 FULL JOIN t3 USING(b))
279 | |--SCAN t3 LEFT-JOIN
284 do_execsql_test 320 {
285 WITH t23 AS NOT MATERIALIZED (SELECT * FROM t2 FULL JOIN t3 USING(b))
293 WITH t23 AS NOT MATERIALIZED (SELECT * FROM t2 FULL JOIN t3 USING(b))
302 do_execsql_test 330 {
303 WITH t23 AS (SELECT * FROM t2 FULL JOIN t3 USING(b))
311 WITH t23 AS (SELECT * FROM t2 FULL JOIN t3 USING(b))
322 # https://sqlite.org/forum/forumpost/1d571c02963355ed
324 # Just because a CTE is used more than once, does not mean it should be
325 # marked with M10d_Yes and hence prohibited from participating in the
326 # query flattening optimization.
330 CREATE TABLE raw(country,date,total,delta, UNIQUE(country,date));
334 init(country, date, fin) AS (SELECT country, min(date), max(date) FROM raw WHERE total > 0 GROUP BY country),
335 src(country, date) AS (SELECT raw.country, raw.date
336 FROM raw JOIN init i on raw.country = i.country AND raw.date > i.date
337 ORDER BY raw.country, raw.date),
338 vals(country, date, x, y) AS (SELECT src.country, src.date, julianday(raw.date) - julianday(src.date), log(delta+1)
339 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),
340 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),
341 mult(country, date, m) AS (SELECT country, date, 1.0/(x2 * n - x * x) FROM sums),
342 inv(country, date, a,b,c,d) AS (SELECT mult.country, mult.date, n * m, -x * m, -x * m, x2 * m
343 FROM mult JOIN sums on sums.country=mult.country AND mult.date=sums.date),
344 fit(country, date, a, b) AS (SELECT inv.country, inv.date, a * xy + b * y, c * xy + d * y
346 JOIN mult on mult.country = inv.country AND mult.date = inv.date
347 JOIN sums on sums.country = mult.country AND sums.date = mult.date
349 SELECT *, nFin/nPrev - 1 AS growth, log(2)/log(nFin/nPrev) AS doubling
350 FROM (SELECT f.*, exp(b) - 1 AS nFin, exp(a* (-1) + b) - 1 AS nPrev
351 FROM fit f JOIN init i on i.country = f.country AND f.date <= date(i.fin,'-3 days'))
352 WHERE nPrev > 0 AND nFin > 0;
357 | | |--MATERIALIZE init
358 | | | `--SCAN raw USING INDEX sqlite_autoindex_raw_1
360 | | |--SEARCH raw USING COVERING INDEX sqlite_autoindex_raw_1 (country=? AND date>?)
361 | | `--USE TEMP B-TREE FOR ORDER BY
363 | |--SEARCH raw USING INDEX sqlite_autoindex_raw_1 (country=? AND date>? AND date<?)
364 | `--USE TEMP B-TREE FOR GROUP BY
366 |--BLOOM FILTER ON sums (country=? AND date=?)
367 |--SEARCH sums USING AUTOMATIC COVERING INDEX (country=? AND date=?)
368 |--BLOOM FILTER ON sums (country=? AND date=?)
369 |--SEARCH sums USING AUTOMATIC COVERING INDEX (country=? AND date=?)
370 |--BLOOM FILTER ON sums (country=? AND date=?)
371 |--SEARCH sums USING AUTOMATIC COVERING INDEX (country=? AND date=?)
372 |--BLOOM FILTER ON i (country=?)
373 `--SEARCH i USING AUTOMATIC COVERING INDEX (country=?)