xref: /sqlite-3.40.0/test/with3.test (revision a3fc683c)
16e772266Sdrh# 2015-11-07
26e772266Sdrh#
36e772266Sdrh# The author disclaims copyright to this source code.  In place of
46e772266Sdrh# a legal notice, here is a blessing:
56e772266Sdrh#
66e772266Sdrh#    May you do good and not evil.
76e772266Sdrh#    May you find forgiveness for yourself and forgive others.
86e772266Sdrh#    May you share freely, never taking more than you give.
96e772266Sdrh#
106e772266Sdrh#***********************************************************************
116e772266Sdrh# This file implements regression tests for SQLite library.  The
126e772266Sdrh# focus of this file is testing the WITH clause.
136e772266Sdrh#
146e772266Sdrh
156e772266Sdrhset testdir [file dirname $argv0]
166e772266Sdrhsource $testdir/tester.tcl
176e772266Sdrhset ::testprefix with3
186e772266Sdrh
196e772266Sdrhifcapable {!cte} {
206e772266Sdrh  finish_test
216e772266Sdrh  return
226e772266Sdrh}
236e772266Sdrh
246e772266Sdrh# Test problems found by Kostya Serebryany using
256e772266Sdrh# LibFuzzer.  (http://llvm.org/docs/LibFuzzer.html)
266e772266Sdrh#
276e772266Sdrhdo_catchsql_test 1.0 {
286e772266Sdrh  WITH i(x) AS (
296e772266Sdrh    WITH j AS (SELECT 10)
306e772266Sdrh    SELECT 5 FROM t0 UNION SELECT 8 FROM m
316e772266Sdrh  )
326e772266Sdrh  SELECT * FROM i;
3334055854Sdrh} {1 {no such table: m}}
3446a31cdfSdrh
3546a31cdfSdrh# 2019-11-09 dbfuzzcheck find
3646a31cdfSdrhdo_catchsql_test 1.1 {
3746a31cdfSdrh  CREATE VIEW v1(x,y) AS
3846a31cdfSdrh    WITH t1(a,b) AS (VALUES(1,2))
3946a31cdfSdrh    SELECT * FROM nosuchtable JOIN t1;
4046a31cdfSdrh  SELECT * FROM v1;
4146a31cdfSdrh} {1 {no such table: main.nosuchtable}}
426e772266Sdrh
436e772266Sdrh# Additional test cases that came out of the work to
446e772266Sdrh# fix for Kostya's problem.
456e772266Sdrh#
466e772266Sdrhdo_execsql_test 2.0 {
476e772266Sdrh WITH
486e772266Sdrh  x1 AS (SELECT 10),
496e772266Sdrh  x2 AS (SELECT 11),
506e772266Sdrh  x3 AS (
516e772266Sdrh    SELECT * FROM x1 UNION ALL SELECT * FROM x2
526e772266Sdrh  ),
536e772266Sdrh  x4 AS (
546e772266Sdrh    WITH
556e772266Sdrh    x1 AS (SELECT 12),
566e772266Sdrh    x2 AS (SELECT 13)
576e772266Sdrh    SELECT * FROM x3
586e772266Sdrh  )
596e772266Sdrh  SELECT * FROM x4;
606e772266Sdrh
616e772266Sdrh} {10 11}
626e772266Sdrh
636e772266Sdrhdo_execsql_test 2.1 {
646e772266Sdrh  CREATE TABLE t1(x);
656e772266Sdrh  WITH
666e772266Sdrh    x1(a) AS (values(100))
676e772266Sdrh  INSERT INTO t1(x)
686e772266Sdrh    SELECT * FROM (WITH x2(y) AS (SELECT * FROM x1) SELECT y+a FROM x1, x2);
696e772266Sdrh  SELECT * FROM t1;
706e772266Sdrh} {200}
716e772266Sdrh
7269b9383eSdan#-------------------------------------------------------------------------
7369b9383eSdan# Test that the planner notices LIMIT clauses on recursive WITH queries.
7469b9383eSdan#
7569b9383eSdan
7669b9383eSdanifcapable analyze {
7769b9383eSdan  do_execsql_test 3.1.1 {
7869b9383eSdan    CREATE TABLE y1(a, b);
7969b9383eSdan    CREATE INDEX y1a ON y1(a);
8069b9383eSdan
8169b9383eSdan    WITH cnt(i) AS ( SELECT 1 UNION ALL SELECT i+1 FROM cnt LIMIT 1000)
8269b9383eSdan      INSERT INTO y1 SELECT i%10, i FROM cnt;
8369b9383eSdan    ANALYZE;
8469b9383eSdan
8569b9383eSdan  }
8669b9383eSdan
8769b9383eSdan  do_eqp_test 3.1.2 {
8869b9383eSdan    WITH cnt(i) AS ( SELECT 1 UNION ALL SELECT i+1 FROM cnt LIMIT 1)
8969b9383eSdan    SELECT * FROM cnt, y1 WHERE i=a
90b3f0276bSdrh  } [string map {"\n  " \n} {
91b3f0276bSdrh    QUERY PLAN
928210233cSdrh    |--MATERIALIZE cnt
93b3f0276bSdrh    |  |--SETUP
94fa16f5d9Sdrh    |  |  `--SCAN CONSTANT ROW
95b3f0276bSdrh    |  `--RECURSIVE STEP
968210233cSdrh    |     `--SCAN cnt
978210233cSdrh    |--SCAN cnt
988210233cSdrh    `--SEARCH y1 USING INDEX y1a (a=?)
99b3f0276bSdrh  }]
10069b9383eSdan
10169b9383eSdan  do_eqp_test 3.1.3 {
10269b9383eSdan    WITH cnt(i) AS ( SELECT 1 UNION ALL SELECT i+1 FROM cnt LIMIT 1000000)
10369b9383eSdan    SELECT * FROM cnt, y1 WHERE i=a
104b3f0276bSdrh  } [string map {"\n  " \n} {
105b3f0276bSdrh    QUERY PLAN
1068210233cSdrh    |--MATERIALIZE cnt
107b3f0276bSdrh    |  |--SETUP
108fa16f5d9Sdrh    |  |  `--SCAN CONSTANT ROW
109b3f0276bSdrh    |  `--RECURSIVE STEP
1108210233cSdrh    |     `--SCAN cnt
1118210233cSdrh    |--SCAN y1
1128210233cSdrh    `--SEARCH cnt USING AUTOMATIC COVERING INDEX (i=?)
113b3f0276bSdrh  }]
11469b9383eSdan}
11569b9383eSdan
11669b9383eSdando_execsql_test 3.2.1 {
11769b9383eSdan  CREATE TABLE w1(pk INTEGER PRIMARY KEY, x INTEGER);
11869b9383eSdan  CREATE TABLE w2(pk INTEGER PRIMARY KEY);
11969b9383eSdan}
12069b9383eSdan
12169b9383eSdando_eqp_test 3.2.2 {
12269b9383eSdan  WITH RECURSIVE c(w,id) AS (SELECT 0, (SELECT pk FROM w2 LIMIT 1)
12369b9383eSdan     UNION ALL SELECT c.w + 1, x FROM w1, c LIMIT 1)
12469b9383eSdan     SELECT * FROM c, w2, w1
12569b9383eSdan     WHERE c.id=w2.pk AND c.id=w1.pk;
12669b9383eSdan} {
127b3f0276bSdrh  QUERY PLAN
1288210233cSdrh  |--MATERIALIZE c
129b3f0276bSdrh  |  |--SETUP
130fa16f5d9Sdrh  |  |  |--SCAN CONSTANT ROW
131bd462bccSdrh  |  |  `--SCALAR SUBQUERY xxxxxx
1328210233cSdrh  |  |     `--SCAN w2
133b3f0276bSdrh  |  `--RECURSIVE STEP
134*a3fc683cSdrh  |     |--SCAN c
135*a3fc683cSdrh  |     `--SCAN w1
1368210233cSdrh  |--SCAN c
1378210233cSdrh  |--SEARCH w2 USING INTEGER PRIMARY KEY (rowid=?)
1388210233cSdrh  `--SEARCH w1 USING INTEGER PRIMARY KEY (rowid=?)
13969b9383eSdan}
14069b9383eSdan
141a5129720Sdando_execsql_test 4.0 {
142a5129720Sdan  WITH t5(t5col1) AS (
143a5129720Sdan    SELECT (
144a5129720Sdan      WITH t3(t3col1) AS (
145a5129720Sdan        WITH t2 AS (
146a5129720Sdan          WITH t1 AS (SELECT 1 AS c1 GROUP BY 1)
147a5129720Sdan          SELECT a.c1 FROM t1 AS a, t1 AS b
148a5129720Sdan          WHERE anoncol1 = 1
149a5129720Sdan        )
150a5129720Sdan        SELECT (SELECT 1 FROM t2) FROM t2
151a5129720Sdan      )
152a5129720Sdan      SELECT t3col1 FROM t3 WHERE t3col1
153a5129720Sdan    ) FROM (SELECT 1 AS anoncol1)
154a5129720Sdan  )
155a5129720Sdan  SELECT t5col1, t5col1 FROM t5
156a5129720Sdan} {1 1}
157a5129720Sdando_execsql_test 4.1 {
158a5129720Sdan  SELECT EXISTS (
159a5129720Sdan    WITH RECURSIVE Table0 AS (
160a5129720Sdan      WITH RECURSIVE Table0(Col0) AS (SELECT ALL 1  )
161a5129720Sdan      SELECT ALL (
162a5129720Sdan        WITH RECURSIVE Table0 AS (
163a5129720Sdan          WITH RECURSIVE Table0 AS (
164a5129720Sdan            WITH RECURSIVE Table0 AS (SELECT DISTINCT 1  GROUP BY 1  )
165a5129720Sdan            SELECT DISTINCT * FROM Table0 NATURAL INNER JOIN Table0
166a5129720Sdan            WHERE Col0 = 1
167a5129720Sdan          )
168a5129720Sdan          SELECT ALL (SELECT DISTINCT * FROM Table0) FROM Table0 WHERE Col0 = 1
169a5129720Sdan        )
170a5129720Sdan        SELECT ALL * FROM Table0  NATURAL INNER JOIN  Table0
171a5129720Sdan      ) FROM Table0 )
172a5129720Sdan      SELECT DISTINCT * FROM Table0  NATURAL INNER JOIN  Table0
173a5129720Sdan    );
174a5129720Sdan} {1}
175a5129720Sdan
1761ee02a1cSdrh# 2020-01-18 chrome ticket 1043236
1771ee02a1cSdrh# Correct handling of the sequence:
1781ee02a1cSdrh#    OP_OpenEphem
1791ee02a1cSdrh#    OP_OpenDup
1801ee02a1cSdrh#    Op_OpenEphem
1811ee02a1cSdrh#    OP_OpenDup
1821ee02a1cSdrh#
1831ee02a1cSdrhdo_execsql_test 4.2 {
1841ee02a1cSdrh  SELECT (
1851ee02a1cSdrh    WITH t1(a) AS (VALUES(1))
1861ee02a1cSdrh    SELECT (
1871ee02a1cSdrh      WITH t2(b) AS (
1881ee02a1cSdrh        WITH t3(c) AS (
1891ee02a1cSdrh          WITH t4(d) AS (VALUES('elvis'))
1901ee02a1cSdrh          SELECT t4a.d FROM t4 AS t4a JOIN t4 AS t4b LEFT JOIN t4 AS t4c
1911ee02a1cSdrh        )
1921ee02a1cSdrh        SELECT c FROM t3 WHERE a = 1
1931ee02a1cSdrh      )
1941ee02a1cSdrh      SELECT t2a.b FROM t2 AS t2a JOIN t2 AS t2x
1951ee02a1cSdrh    )
1961ee02a1cSdrh    FROM t1 GROUP BY 1
1971ee02a1cSdrh  )
1981ee02a1cSdrh  GROUP BY 1;
1991ee02a1cSdrh} {elvis}
200a5129720Sdan
2018794c68aSdrh# 2021-02-13
2028794c68aSdrh# Avoid manifesting the same CTE multiple times.
2038794c68aSdrh#
2048794c68aSdrhdo_eqp_test 5.1 {
2058794c68aSdrh  WITH RECURSIVE c(x) AS (VALUES(0) UNION ALL SELECT x+1 FROM c WHERE x<1)
2068794c68aSdrh  SELECT x1.x||x2.x||x3.x||x4.x FROM c AS x1, c AS x2, c AS x3, c AS x4
2078794c68aSdrh  ORDER BY 1;
2088794c68aSdrh} {
2098794c68aSdrh  QUERY PLAN
2102f2091b1Sdrh  |--MATERIALIZE c
2118794c68aSdrh  |  |--SETUP
2128794c68aSdrh  |  |  `--SCAN CONSTANT ROW
2138794c68aSdrh  |  `--RECURSIVE STEP
2148210233cSdrh  |     `--SCAN c
2158210233cSdrh  |--SCAN x1
2168210233cSdrh  |--SCAN x2
2178210233cSdrh  |--SCAN x3
2188210233cSdrh  |--SCAN x4
2198794c68aSdrh  `--USE TEMP B-TREE FOR ORDER BY
2208794c68aSdrh}
2218794c68aSdrhdo_execsql_test 5.2 {
2228794c68aSdrh  WITH RECURSIVE c(x) AS (VALUES(0) UNION ALL SELECT x+1 FROM c WHERE x<1)
2238794c68aSdrh  SELECT x1.x||x2.x||x3.x||x4.x FROM c AS x1, c AS x2, c AS x3, c AS x4
2248794c68aSdrh  ORDER BY 1;
2258794c68aSdrh} {0000 0001 0010 0011 0100 0101 0110 0111 1000 1001 1010 1011 1100 1101 1110 1111}
2268794c68aSdrh
227ca237a8bSdan#-------------------------------------------------------------------------
228ca237a8bSdan# At one point this would incorrectly report "circular reference: cte1"
229ca237a8bSdan#
230ca237a8bSdando_catchsql_test 6.0 {
231ca237a8bSdan  with
232ca237a8bSdan    cte1(x, y) AS ( select 1, 2, 3 ),
233ca237a8bSdan    cte2(z) as ( select 1 from cte1 )
234ca237a8bSdan  select * from cte2, cte1;
235ca237a8bSdan} {1 {table cte1 has 3 values for 2 columns}}
236ca237a8bSdan
237ca237a8bSdando_catchsql_test 6.1 {
238ca237a8bSdan  with
239ca237a8bSdan    cte1(x, y) AS ( select 1, 2, 3 ),
240ca237a8bSdan    cte2(z) as ( select 1 from cte1 UNION ALL SELECT z+1 FROM cte2 WHERE z<5)
241ca237a8bSdan  select * from cte2, cte1;
242ca237a8bSdan} {1 {table cte1 has 3 values for 2 columns}}
243ca237a8bSdan
2448794c68aSdrh
2458794c68aSdrh
2468794c68aSdrh
2476e772266Sdrhfinish_test
248