xref: /sqlite-3.40.0/test/with1.test (revision 67f70bea)
17d562dbeSdan# 2014 January 11
27d562dbeSdan#
37d562dbeSdan# The author disclaims copyright to this source code.  In place of
47d562dbeSdan# a legal notice, here is a blessing:
57d562dbeSdan#
67d562dbeSdan#    May you do good and not evil.
77d562dbeSdan#    May you find forgiveness for yourself and forgive others.
87d562dbeSdan#    May you share freely, never taking more than you give.
97d562dbeSdan#
107d562dbeSdan#***********************************************************************
117d562dbeSdan# This file implements regression tests for SQLite library.  The
127d562dbeSdan# focus of this file is testing the WITH clause.
137d562dbeSdan#
147d562dbeSdan
157d562dbeSdanset testdir [file dirname $argv0]
167d562dbeSdansource $testdir/tester.tcl
177d562dbeSdanset ::testprefix with1
187d562dbeSdan
19eede6a53Sdanifcapable {!cte} {
20eede6a53Sdan  finish_test
21eede6a53Sdan  return
22eede6a53Sdan}
23eede6a53Sdan
247d562dbeSdando_execsql_test 1.0 {
257d562dbeSdan  CREATE TABLE t1(x INTEGER, y INTEGER);
267d562dbeSdan  WITH x(a) AS ( SELECT * FROM t1) SELECT 10
277d562dbeSdan} {10}
287d562dbeSdan
297d562dbeSdando_execsql_test 1.1 {
307d562dbeSdan  SELECT * FROM ( WITH x AS ( SELECT * FROM t1) SELECT 10 );
317d562dbeSdan} {10}
327d562dbeSdan
337d562dbeSdando_execsql_test 1.2 {
347d562dbeSdan  WITH x(a) AS ( SELECT * FROM t1) INSERT INTO t1 VALUES(1,2);
357d562dbeSdan} {}
367d562dbeSdan
377d562dbeSdando_execsql_test 1.3 {
387d562dbeSdan  WITH x(a) AS ( SELECT * FROM t1) DELETE FROM t1;
397d562dbeSdan} {}
407d562dbeSdan
417d562dbeSdando_execsql_test 1.4 {
427d562dbeSdan  WITH x(a) AS ( SELECT * FROM t1) UPDATE t1 SET x = y;
437d562dbeSdan} {}
447d562dbeSdan
454e9119d9Sdan#--------------------------------------------------------------------------
464e9119d9Sdan
474e9119d9Sdando_execsql_test 2.1 {
484e9119d9Sdan  DROP TABLE IF EXISTS t1;
494e9119d9Sdan  CREATE TABLE t1(x);
504e9119d9Sdan  INSERT INTO t1 VALUES(1);
514e9119d9Sdan  INSERT INTO t1 VALUES(2);
524e9119d9Sdan  WITH tmp AS ( SELECT * FROM t1 ) SELECT x FROM tmp;
534e9119d9Sdan} {1 2}
544e9119d9Sdan
554e9119d9Sdando_execsql_test 2.2 {
564e9119d9Sdan  WITH tmp(a) AS ( SELECT * FROM t1 ) SELECT a FROM tmp;
574e9119d9Sdan} {1 2}
584e9119d9Sdan
594e9119d9Sdando_execsql_test 2.3 {
604e9119d9Sdan  SELECT * FROM (
614e9119d9Sdan    WITH tmp(a) AS ( SELECT * FROM t1 ) SELECT a FROM tmp
624e9119d9Sdan  );
634e9119d9Sdan} {1 2}
644e9119d9Sdan
654e9119d9Sdando_execsql_test 2.4 {
664e9119d9Sdan  WITH tmp1(a) AS ( SELECT * FROM t1 ),
674e9119d9Sdan       tmp2(x) AS ( SELECT * FROM tmp1)
684e9119d9Sdan  SELECT * FROM tmp2;
694e9119d9Sdan} {1 2}
704e9119d9Sdan
714e9119d9Sdando_execsql_test 2.5 {
724e9119d9Sdan  WITH tmp2(x) AS ( SELECT * FROM tmp1),
734e9119d9Sdan       tmp1(a) AS ( SELECT * FROM t1 )
744e9119d9Sdan  SELECT * FROM tmp2;
754e9119d9Sdan} {1 2}
764e9119d9Sdan
774e9119d9Sdan#-------------------------------------------------------------------------
784e9119d9Sdando_catchsql_test 3.1 {
794e9119d9Sdan  WITH tmp2(x) AS ( SELECT * FROM tmp1 ),
804e9119d9Sdan       tmp1(a) AS ( SELECT * FROM tmp2 )
814e9119d9Sdan  SELECT * FROM tmp1;
82727a99f1Sdrh} {1 {circular reference: tmp1}}
834e9119d9Sdan
844e9119d9Sdando_catchsql_test 3.2 {
854e9119d9Sdan  CREATE TABLE t2(x INTEGER);
864e9119d9Sdan  WITH tmp(a) AS (SELECT * FROM t1),
874e9119d9Sdan       tmp(a) AS (SELECT * FROM t1)
884e9119d9Sdan  SELECT * FROM tmp;
89727a99f1Sdrh} {1 {duplicate WITH table name: tmp}}
904e9119d9Sdan
914e9119d9Sdando_execsql_test 3.3 {
924e9119d9Sdan  CREATE TABLE t3(x);
934e9119d9Sdan  CREATE TABLE t4(x);
944e9119d9Sdan
954e9119d9Sdan  INSERT INTO t3 VALUES('T3');
964e9119d9Sdan  INSERT INTO t4 VALUES('T4');
974e9119d9Sdan
984e9119d9Sdan  WITH t3(a) AS (SELECT * FROM t4)
994e9119d9Sdan  SELECT * FROM t3;
1004e9119d9Sdan} {T4}
1014e9119d9Sdan
1024e9119d9Sdando_execsql_test 3.4 {
1034e9119d9Sdan  WITH tmp  AS ( SELECT * FROM t3 ),
1044e9119d9Sdan       tmp2 AS ( WITH tmp AS ( SELECT * FROM t4 ) SELECT * FROM tmp )
1054e9119d9Sdan  SELECT * FROM tmp2;
1064e9119d9Sdan} {T4}
1074e9119d9Sdan
1084e9119d9Sdando_execsql_test 3.5 {
1094e9119d9Sdan  WITH tmp  AS ( SELECT * FROM t3 ),
1104e9119d9Sdan       tmp2 AS ( WITH xxxx AS ( SELECT * FROM t4 ) SELECT * FROM tmp )
1114e9119d9Sdan  SELECT * FROM tmp2;
1124e9119d9Sdan} {T3}
1134e9119d9Sdan
1144e9119d9Sdando_catchsql_test 3.6 {
1154e9119d9Sdan  WITH tmp AS ( SELECT * FROM t3 ),
1164e9119d9Sdan  SELECT * FROM tmp;
1174e9119d9Sdan} {1 {near "SELECT": syntax error}}
1184e9119d9Sdan
1194e9119d9Sdan#-------------------------------------------------------------------------
1204e9119d9Sdando_execsql_test 4.1 {
1214e9119d9Sdan  DROP TABLE IF EXISTS t1;
1224e9119d9Sdan  CREATE TABLE t1(x);
1234e9119d9Sdan  INSERT INTO t1 VALUES(1);
1244e9119d9Sdan  INSERT INTO t1 VALUES(2);
1254e9119d9Sdan  INSERT INTO t1 VALUES(3);
1264e9119d9Sdan  INSERT INTO t1 VALUES(4);
1274e9119d9Sdan
1284e9119d9Sdan  WITH dset AS ( SELECT 2 UNION ALL SELECT 4 )
1294e9119d9Sdan  DELETE FROM t1 WHERE x IN dset;
1304e9119d9Sdan  SELECT * FROM t1;
1314e9119d9Sdan} {1 3}
1324e9119d9Sdan
1334e9119d9Sdando_execsql_test 4.2 {
1344e9119d9Sdan  WITH iset AS ( SELECT 2 UNION ALL SELECT 4 )
1354e9119d9Sdan  INSERT INTO t1 SELECT * FROM iset;
1364e9119d9Sdan  SELECT * FROM t1;
1374e9119d9Sdan} {1 3 2 4}
1384e9119d9Sdan
1394e9119d9Sdando_execsql_test 4.3 {
1404e9119d9Sdan  WITH uset(a, b) AS ( SELECT 2, 8 UNION ALL SELECT 4, 9 )
1414e9119d9Sdan  UPDATE t1 SET x = COALESCE( (SELECT b FROM uset WHERE a=x), x );
1424e9119d9Sdan  SELECT * FROM t1;
1434e9119d9Sdan} {1 3 8 9}
1444e9119d9Sdan
1458ce7184bSdan#-------------------------------------------------------------------------
1468ce7184bSdan#
1478ce7184bSdando_execsql_test 5.1 {
1488ce7184bSdan  WITH i(x) AS ( VALUES(1) UNION ALL SELECT x+1 FROM i)
1498ce7184bSdan  SELECT x FROM i LIMIT 10;
1508ce7184bSdan} {1 2 3 4 5 6 7 8 9 10}
1518ce7184bSdan
1528ce7184bSdando_catchsql_test 5.2 {
1538ce7184bSdan  WITH i(x) AS ( VALUES(1) UNION ALL SELECT x+1 FROM i ORDER BY 1)
1548ce7184bSdan  SELECT x FROM i LIMIT 10;
155fe1c6bb9Sdrh} {0 {1 2 3 4 5 6 7 8 9 10}}
156fe1c6bb9Sdrh
157fe1c6bb9Sdrhdo_execsql_test 5.2.1 {
158fe1c6bb9Sdrh  CREATE TABLE edge(xfrom, xto, seq, PRIMARY KEY(xfrom, xto)) WITHOUT ROWID;
159fe1c6bb9Sdrh  INSERT INTO edge VALUES(0, 1, 10);
160fe1c6bb9Sdrh  INSERT INTO edge VALUES(1, 2, 20);
161fe1c6bb9Sdrh  INSERT INTO edge VALUES(0, 3, 30);
162fe1c6bb9Sdrh  INSERT INTO edge VALUES(2, 4, 40);
163fe1c6bb9Sdrh  INSERT INTO edge VALUES(3, 4, 40);
164fe1c6bb9Sdrh  INSERT INTO edge VALUES(2, 5, 50);
165fe1c6bb9Sdrh  INSERT INTO edge VALUES(3, 6, 60);
166fe1c6bb9Sdrh  INSERT INTO edge VALUES(5, 7, 70);
167fe1c6bb9Sdrh  INSERT INTO edge VALUES(3, 7, 70);
168fe1c6bb9Sdrh  INSERT INTO edge VALUES(4, 8, 80);
169fe1c6bb9Sdrh  INSERT INTO edge VALUES(7, 8, 80);
170fe1c6bb9Sdrh  INSERT INTO edge VALUES(8, 9, 90);
171fe1c6bb9Sdrh
172fe1c6bb9Sdrh  WITH RECURSIVE
173fe1c6bb9Sdrh    ancest(id, mtime) AS
174fe1c6bb9Sdrh      (VALUES(0, 0)
175fe1c6bb9Sdrh       UNION
176fe1c6bb9Sdrh       SELECT edge.xto, edge.seq FROM edge, ancest
177fe1c6bb9Sdrh        WHERE edge.xfrom=ancest.id
178fe1c6bb9Sdrh        ORDER BY 2
179fe1c6bb9Sdrh      )
180fe1c6bb9Sdrh  SELECT * FROM ancest;
181fe1c6bb9Sdrh} {0 0 1 10 2 20 3 30 4 40 5 50 6 60 7 70 8 80 9 90}
182fe1c6bb9Sdrhdo_execsql_test 5.2.2 {
183fe1c6bb9Sdrh  WITH RECURSIVE
184fe1c6bb9Sdrh    ancest(id, mtime) AS
185fe1c6bb9Sdrh      (VALUES(0, 0)
186fe1c6bb9Sdrh       UNION ALL
187fe1c6bb9Sdrh       SELECT edge.xto, edge.seq FROM edge, ancest
188fe1c6bb9Sdrh        WHERE edge.xfrom=ancest.id
189fe1c6bb9Sdrh        ORDER BY 2
190fe1c6bb9Sdrh      )
191fe1c6bb9Sdrh  SELECT * FROM ancest;
192fe1c6bb9Sdrh} {0 0 1 10 2 20 3 30 4 40 4 40 5 50 6 60 7 70 7 70 8 80 8 80 8 80 8 80 9 90 9 90 9 90 9 90}
193aa9ce707Sdrhdo_execsql_test 5.2.3 {
194aa9ce707Sdrh  WITH RECURSIVE
195aa9ce707Sdrh    ancest(id, mtime) AS
196aa9ce707Sdrh      (VALUES(0, 0)
197aa9ce707Sdrh       UNION ALL
198aa9ce707Sdrh       SELECT edge.xto, edge.seq FROM edge, ancest
199aa9ce707Sdrh        WHERE edge.xfrom=ancest.id
200aa9ce707Sdrh        ORDER BY 2 LIMIT 4 OFFSET 2
201aa9ce707Sdrh      )
202aa9ce707Sdrh  SELECT * FROM ancest;
203aa9ce707Sdrh} {2 20 3 30 4 40 4 40}
2048ce7184bSdan
2058ce7184bSdando_catchsql_test 5.3 {
206aa9ce707Sdrh  WITH i(x) AS ( VALUES(1) UNION ALL SELECT x+1 FROM i LIMIT 5)
207aa9ce707Sdrh  SELECT x FROM i;
208aa9ce707Sdrh} {0 {1 2 3 4 5}}
2098ce7184bSdan
2108ce7184bSdando_execsql_test 5.4 {
2118ce7184bSdan  WITH i(x) AS ( VALUES(1) UNION ALL SELECT (x+1)%10 FROM i)
2128ce7184bSdan  SELECT x FROM i LIMIT 20;
2138ce7184bSdan} {1 2 3 4 5 6 7 8 9 0 1 2 3 4 5 6 7 8 9 0}
2148ce7184bSdan
2158ce7184bSdando_execsql_test 5.5 {
2168ce7184bSdan  WITH i(x) AS ( VALUES(1) UNION SELECT (x+1)%10 FROM i)
2178ce7184bSdan  SELECT x FROM i LIMIT 20;
2188ce7184bSdan} {1 2 3 4 5 6 7 8 9 0}
2198ce7184bSdan
22060e7068dSdando_catchsql_test 5.6.1 {
22160e7068dSdan  WITH i(x, y) AS ( VALUES(1) )
22260e7068dSdan  SELECT * FROM i;
223727a99f1Sdrh} {1 {table i has 1 values for 2 columns}}
22460e7068dSdan
22560e7068dSdando_catchsql_test 5.6.2 {
22660e7068dSdan  WITH i(x) AS ( VALUES(1,2) )
22760e7068dSdan  SELECT * FROM i;
228727a99f1Sdrh} {1 {table i has 2 values for 1 columns}}
22960e7068dSdan
23060e7068dSdando_catchsql_test 5.6.3 {
23160e7068dSdan  CREATE TABLE t5(a, b);
23260e7068dSdan  WITH i(x) AS ( SELECT * FROM t5 )
23360e7068dSdan  SELECT * FROM i;
234727a99f1Sdrh} {1 {table i has 2 values for 1 columns}}
23560e7068dSdan
23660e7068dSdando_catchsql_test 5.6.4 {
23760e7068dSdan  WITH i(x) AS ( SELECT 1, 2 UNION ALL SELECT 1 )
23860e7068dSdan  SELECT * FROM i;
239727a99f1Sdrh} {1 {table i has 2 values for 1 columns}}
24060e7068dSdan
24160e7068dSdando_catchsql_test 5.6.5 {
24260e7068dSdan  WITH i(x) AS ( SELECT 1 UNION ALL SELECT 1, 2 )
24360e7068dSdan  SELECT * FROM i;
24460e7068dSdan} {1 {SELECTs to the left and right of UNION ALL do not have the same number of result columns}}
24560e7068dSdan
24660e7068dSdando_catchsql_test 5.6.6 {
24760e7068dSdan  WITH i(x) AS ( SELECT 1 UNION ALL SELECT x+1, x*2 FROM i )
24860e7068dSdan  SELECT * FROM i;
24960e7068dSdan} {1 {SELECTs to the left and right of UNION ALL do not have the same number of result columns}}
25060e7068dSdan
25160e7068dSdando_catchsql_test 5.6.7 {
25260e7068dSdan  WITH i(x) AS ( SELECT 1, 2 UNION SELECT x+1 FROM i )
25360e7068dSdan  SELECT * FROM i;
254727a99f1Sdrh} {1 {table i has 2 values for 1 columns}}
25560e7068dSdan
256bfe31e7fSdan#-------------------------------------------------------------------------
257bfe31e7fSdan#
258bfe31e7fSdando_execsql_test 6.1 {
259bfe31e7fSdan  CREATE TABLE f(
260bfe31e7fSdan      id INTEGER PRIMARY KEY, parentid REFERENCES f, name TEXT
261bfe31e7fSdan  );
262bfe31e7fSdan
263bfe31e7fSdan  INSERT INTO f VALUES(0, NULL, '');
264bfe31e7fSdan  INSERT INTO f VALUES(1, 0, 'bin');
265bfe31e7fSdan    INSERT INTO f VALUES(2, 1, 'true');
266bfe31e7fSdan    INSERT INTO f VALUES(3, 1, 'false');
267bfe31e7fSdan    INSERT INTO f VALUES(4, 1, 'ls');
268bfe31e7fSdan    INSERT INTO f VALUES(5, 1, 'grep');
269bfe31e7fSdan  INSERT INTO f VALUES(6, 0, 'etc');
270bfe31e7fSdan    INSERT INTO f VALUES(7, 6, 'rc.d');
271bfe31e7fSdan      INSERT INTO f VALUES(8, 7, 'rc.apache');
272bfe31e7fSdan      INSERT INTO f VALUES(9, 7, 'rc.samba');
273bfe31e7fSdan  INSERT INTO f VALUES(10, 0, 'home');
274bfe31e7fSdan    INSERT INTO f VALUES(11, 10, 'dan');
275bfe31e7fSdan      INSERT INTO f VALUES(12, 11, 'public_html');
276bfe31e7fSdan        INSERT INTO f VALUES(13, 12, 'index.html');
277bfe31e7fSdan          INSERT INTO f VALUES(14, 13, 'logo.gif');
278bfe31e7fSdan}
279bfe31e7fSdan
280bfe31e7fSdando_execsql_test 6.2 {
281bfe31e7fSdan  WITH flat(fid, fpath) AS (
282bfe31e7fSdan    SELECT id, '' FROM f WHERE parentid IS NULL
283bfe31e7fSdan    UNION ALL
28462ba4e41Sdan    SELECT id, fpath || '/' || name FROM f, flat WHERE parentid=fid
285bfe31e7fSdan  )
286bfe31e7fSdan  SELECT fpath FROM flat WHERE fpath!='' ORDER BY 1;
287bfe31e7fSdan} {
288bfe31e7fSdan  /bin
289bfe31e7fSdan  /bin/false /bin/grep /bin/ls /bin/true
290bfe31e7fSdan  /etc
291bfe31e7fSdan  /etc/rc.d
292bfe31e7fSdan  /etc/rc.d/rc.apache /etc/rc.d/rc.samba
293bfe31e7fSdan  /home
294bfe31e7fSdan  /home/dan
295bfe31e7fSdan  /home/dan/public_html
296bfe31e7fSdan  /home/dan/public_html/index.html
297bfe31e7fSdan  /home/dan/public_html/index.html/logo.gif
298bfe31e7fSdan}
299bfe31e7fSdan
300f43fe6e9Sdando_execsql_test 6.3 {
301f43fe6e9Sdan  WITH flat(fid, fpath) AS (
302f43fe6e9Sdan    SELECT id, '' FROM f WHERE parentid IS NULL
303f43fe6e9Sdan    UNION ALL
30462ba4e41Sdan    SELECT id, fpath || '/' || name FROM f, flat WHERE parentid=fid
305f43fe6e9Sdan  )
306f43fe6e9Sdan  SELECT count(*) FROM flat;
307f43fe6e9Sdan} {15}
308f43fe6e9Sdan
309f43fe6e9Sdando_execsql_test 6.4 {
310f43fe6e9Sdan  WITH x(i) AS (
311f43fe6e9Sdan    SELECT 1
312f43fe6e9Sdan    UNION ALL
313f43fe6e9Sdan    SELECT i+1 FROM x WHERE i<10
314f43fe6e9Sdan  )
315f43fe6e9Sdan  SELECT count(*) FROM x
316f43fe6e9Sdan} {10}
317f43fe6e9Sdan
318f43fe6e9Sdan
319f2655fe8Sdan#-------------------------------------------------------------------------
320f2655fe8Sdan
321f2655fe8Sdando_execsql_test 7.1 {
322f2655fe8Sdan  CREATE TABLE tree(i, p);
323f2655fe8Sdan  INSERT INTO tree VALUES(1, NULL);
324f2655fe8Sdan  INSERT INTO tree VALUES(2, 1);
325f2655fe8Sdan  INSERT INTO tree VALUES(3, 1);
326f2655fe8Sdan  INSERT INTO tree VALUES(4, 2);
327f2655fe8Sdan  INSERT INTO tree VALUES(5, 4);
328f2655fe8Sdan}
329f2655fe8Sdan
330f2655fe8Sdando_execsql_test 7.2 {
331f2655fe8Sdan  WITH t(id, path) AS (
332f2655fe8Sdan    SELECT i, '' FROM tree WHERE p IS NULL
333f2655fe8Sdan    UNION ALL
334f2655fe8Sdan    SELECT i, path || '/' || i FROM tree, t WHERE p = id
335f2655fe8Sdan  )
336f2655fe8Sdan  SELECT path FROM t;
337f2655fe8Sdan} {{} /2 /3 /2/4 /2/4/5}
338f2655fe8Sdan
339f2655fe8Sdando_execsql_test 7.3 {
340f2655fe8Sdan  WITH t(id) AS (
341f2655fe8Sdan    VALUES(2)
342f2655fe8Sdan    UNION ALL
343f2655fe8Sdan    SELECT i FROM tree, t WHERE p = id
344f2655fe8Sdan  )
345f2655fe8Sdan  SELECT id FROM t;
346f2655fe8Sdan} {2 4 5}
347f2655fe8Sdan
348f2655fe8Sdando_catchsql_test 7.4 {
349f2655fe8Sdan  WITH t(id) AS (
350f2655fe8Sdan    VALUES(2)
351f2655fe8Sdan    UNION ALL
352f2655fe8Sdan    SELECT i FROM tree WHERE p IN (SELECT id FROM t)
353f2655fe8Sdan  )
354f2655fe8Sdan  SELECT id FROM t;
35534055854Sdrh} {1 {circular reference: t}}
356f2655fe8Sdan
357f2655fe8Sdando_catchsql_test 7.5 {
358f2655fe8Sdan  WITH t(id) AS (
359f2655fe8Sdan    VALUES(2)
360f2655fe8Sdan    UNION ALL
361f2655fe8Sdan    SELECT i FROM tree, t WHERE p = id AND p IN (SELECT id FROM t)
362f2655fe8Sdan  )
363f2655fe8Sdan  SELECT id FROM t;
364727a99f1Sdrh} {1 {multiple recursive references: t}}
365f2655fe8Sdan
366f2655fe8Sdando_catchsql_test 7.6 {
367f2655fe8Sdan  WITH t(id) AS (
368f2655fe8Sdan    SELECT i FROM tree WHERE 2 IN (SELECT id FROM t)
369f2655fe8Sdan    UNION ALL
370f2655fe8Sdan    SELECT i FROM tree, t WHERE p = id
371f2655fe8Sdan  )
372f2655fe8Sdan  SELECT id FROM t;
373727a99f1Sdrh} {1 {circular reference: t}}
374f2655fe8Sdan
37575303a2cSdrh# Compute the mandelbrot set using a recursive query
37675303a2cSdrh#
377b090352bSdrhdo_execsql_test 8.1-mandelbrot {
37875303a2cSdrh  WITH RECURSIVE
37975303a2cSdrh    xaxis(x) AS (VALUES(-2.0) UNION ALL SELECT x+0.05 FROM xaxis WHERE x<1.2),
38075303a2cSdrh    yaxis(y) AS (VALUES(-1.0) UNION ALL SELECT y+0.1 FROM yaxis WHERE y<1.0),
38175303a2cSdrh    m(iter, cx, cy, x, y) AS (
38275303a2cSdrh      SELECT 0, x, y, 0.0, 0.0 FROM xaxis, yaxis
38375303a2cSdrh      UNION ALL
38475303a2cSdrh      SELECT iter+1, cx, cy, x*x-y*y + cx, 2.0*x*y + cy FROM m
38575303a2cSdrh       WHERE (x*x + y*y) < 4.0 AND iter<28
38675303a2cSdrh    ),
38775303a2cSdrh    m2(iter, cx, cy) AS (
38875303a2cSdrh      SELECT max(iter), cx, cy FROM m GROUP BY cx, cy
38975303a2cSdrh    ),
39075303a2cSdrh    a(t) AS (
39175303a2cSdrh      SELECT group_concat( substr(' .+*#', 1+min(iter/7,4), 1), '')
39275303a2cSdrh      FROM m2 GROUP BY cy
39375303a2cSdrh    )
39475303a2cSdrh  SELECT group_concat(rtrim(t),x'0a') FROM a;
39575303a2cSdrh} {{                                    ....#
39675303a2cSdrh                                   ..#*..
39775303a2cSdrh                                 ..+####+.
39875303a2cSdrh                            .......+####....   +
39975303a2cSdrh                           ..##+*##########+.++++
40075303a2cSdrh                          .+.##################+.
40175303a2cSdrh              .............+###################+.+
40275303a2cSdrh              ..++..#.....*#####################+.
40375303a2cSdrh             ...+#######++#######################.
40475303a2cSdrh          ....+*################################.
40575303a2cSdrh #############################################...
40675303a2cSdrh          ....+*################################.
40775303a2cSdrh             ...+#######++#######################.
40875303a2cSdrh              ..++..#.....*#####################+.
40975303a2cSdrh              .............+###################+.+
41075303a2cSdrh                          .+.##################+.
41175303a2cSdrh                           ..##+*##########+.++++
41275303a2cSdrh                            .......+####....   +
41375303a2cSdrh                                 ..+####+.
41475303a2cSdrh                                   ..#*..
41575303a2cSdrh                                    ....#
41675303a2cSdrh                                    +.}}
417f2655fe8Sdan
418717c09c4Sdrh# Solve a sudoku puzzle using a recursive query
419717c09c4Sdrh#
420b090352bSdrhdo_execsql_test 8.2-soduko {
421717c09c4Sdrh  WITH RECURSIVE
422717c09c4Sdrh    input(sud) AS (
423717c09c4Sdrh      VALUES('53..7....6..195....98....6.8...6...34..8.3..17...2...6.6....28....419..5....8..79')
424717c09c4Sdrh    ),
425717c09c4Sdrh
426717c09c4Sdrh    /* A table filled with digits 1..9, inclusive. */
427717c09c4Sdrh    digits(z, lp) AS (
428717c09c4Sdrh      VALUES('1', 1)
429717c09c4Sdrh      UNION ALL SELECT
430717c09c4Sdrh      CAST(lp+1 AS TEXT), lp+1 FROM digits WHERE lp<9
431717c09c4Sdrh    ),
432717c09c4Sdrh
433717c09c4Sdrh    /* The tricky bit. */
434717c09c4Sdrh    x(s, ind) AS (
435717c09c4Sdrh      SELECT sud, instr(sud, '.') FROM input
436717c09c4Sdrh      UNION ALL
437717c09c4Sdrh      SELECT
438717c09c4Sdrh        substr(s, 1, ind-1) || z || substr(s, ind+1),
439717c09c4Sdrh        instr( substr(s, 1, ind-1) || z || substr(s, ind+1), '.' )
440717c09c4Sdrh       FROM x, digits AS z
441717c09c4Sdrh      WHERE ind>0
442717c09c4Sdrh        AND NOT EXISTS (
443717c09c4Sdrh              SELECT 1
444717c09c4Sdrh                FROM digits AS lp
445717c09c4Sdrh               WHERE z.z = substr(s, ((ind-1)/9)*9 + lp, 1)
446717c09c4Sdrh                  OR z.z = substr(s, ((ind-1)%9) + (lp-1)*9 + 1, 1)
447717c09c4Sdrh                  OR z.z = substr(s, (((ind-1)/3) % 3) * 3
448717c09c4Sdrh                          + ((ind-1)/27) * 27 + lp
449717c09c4Sdrh                          + ((lp-1) / 3) * 6, 1)
450717c09c4Sdrh           )
451717c09c4Sdrh    )
452717c09c4Sdrh  SELECT s FROM x WHERE ind=0;
453717c09c4Sdrh} {534678912672195348198342567859761423426853791713924856961537284287419635345286179}
454717c09c4Sdrh
45505d3dc29Sdan#--------------------------------------------------------------------------
45605d3dc29Sdan# Some tests that use LIMIT and OFFSET in the definition of recursive CTEs.
45705d3dc29Sdan#
45805d3dc29Sdanset I [list 1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20]
45905d3dc29Sdanproc limit_test {tn iLimit iOffset} {
46005d3dc29Sdan  if {$iOffset < 0} { set iOffset 0 }
46105d3dc29Sdan  if {$iLimit < 0 } {
46205d3dc29Sdan    set result [lrange $::I $iOffset end]
46305d3dc29Sdan  } else {
46405d3dc29Sdan    set result [lrange $::I $iOffset [expr $iLimit+$iOffset-1]]
46505d3dc29Sdan  }
46605d3dc29Sdan  uplevel [list do_execsql_test $tn [subst -nocommands {
46705d3dc29Sdan    WITH ii(a) AS (
46805d3dc29Sdan      VALUES(1)
46905d3dc29Sdan      UNION ALL
47005d3dc29Sdan      SELECT a+1 FROM ii WHERE a<20
47105d3dc29Sdan      LIMIT $iLimit OFFSET $iOffset
47205d3dc29Sdan    )
47305d3dc29Sdan    SELECT * FROM ii
47405d3dc29Sdan  }] $result]
47505d3dc29Sdan}
47605d3dc29Sdan
47705d3dc29Sdanlimit_test 9.1    20  0
47805d3dc29Sdanlimit_test 9.2     0  0
47905d3dc29Sdanlimit_test 9.3    19  1
48005d3dc29Sdanlimit_test 9.4    20 -1
48105d3dc29Sdanlimit_test 9.5     5  5
48205d3dc29Sdanlimit_test 9.6     0 -1
48305d3dc29Sdanlimit_test 9.7    40 -1
48405d3dc29Sdanlimit_test 9.8    -1 -1
48505d3dc29Sdanlimit_test 9.9    -1 -1
48605d3dc29Sdan
48705d3dc29Sdan#--------------------------------------------------------------------------
48805d3dc29Sdan# Test the ORDER BY clause on recursive tables.
48905d3dc29Sdan#
49005d3dc29Sdan
49105d3dc29Sdando_execsql_test 10.1 {
49205d3dc29Sdan  DROP TABLE IF EXISTS tree;
49305d3dc29Sdan  CREATE TABLE tree(id INTEGER PRIMARY KEY, parentid, payload);
49405d3dc29Sdan}
49505d3dc29Sdan
49605d3dc29Sdanproc insert_into_tree {L} {
49705d3dc29Sdan  db eval { DELETE FROM tree }
49805d3dc29Sdan  foreach key $L {
49905d3dc29Sdan    unset -nocomplain parentid
50005d3dc29Sdan    foreach seg [split $key /] {
50105d3dc29Sdan      if {$seg==""} continue
50205d3dc29Sdan      set id [db one {
50305d3dc29Sdan        SELECT id FROM tree WHERE parentid IS $parentid AND payload=$seg
50405d3dc29Sdan      }]
50505d3dc29Sdan      if {$id==""} {
50605d3dc29Sdan        db eval { INSERT INTO tree VALUES(NULL, $parentid, $seg) }
50705d3dc29Sdan        set parentid [db last_insert_rowid]
50805d3dc29Sdan      } else {
50905d3dc29Sdan        set parentid $id
51005d3dc29Sdan      }
51105d3dc29Sdan    }
51205d3dc29Sdan  }
51305d3dc29Sdan}
51405d3dc29Sdan
51505d3dc29Sdaninsert_into_tree {
51605d3dc29Sdan  /a/a/a
51705d3dc29Sdan  /a/b/c
51805d3dc29Sdan  /a/b/c/d
51905d3dc29Sdan  /a/b/d
52005d3dc29Sdan}
52105d3dc29Sdando_execsql_test 10.2 {
52205d3dc29Sdan  WITH flat(fid, p) AS (
52305d3dc29Sdan    SELECT id, '/' || payload FROM tree WHERE parentid IS NULL
52405d3dc29Sdan    UNION ALL
52505d3dc29Sdan    SELECT id, p || '/' || payload FROM flat, tree WHERE parentid=fid
52605d3dc29Sdan  )
52705d3dc29Sdan  SELECT p FROM flat ORDER BY p;
52805d3dc29Sdan} {
52905d3dc29Sdan  /a /a/a /a/a/a
53005d3dc29Sdan     /a/b /a/b/c /a/b/c/d
53105d3dc29Sdan          /a/b/d
53205d3dc29Sdan}
53305d3dc29Sdan
53405d3dc29Sdan# Scan the tree-structure currently stored in table tree. Return a list
53505d3dc29Sdan# of nodes visited.
53605d3dc29Sdan#
53705d3dc29Sdanproc scan_tree {bDepthFirst bReverse} {
53805d3dc29Sdan
53905d3dc29Sdan  set order "ORDER BY "
54005d3dc29Sdan  if {$bDepthFirst==0} { append order "2 ASC," }
54105d3dc29Sdan  if {$bReverse==0} {
54205d3dc29Sdan    append order " 3 ASC"
54305d3dc29Sdan  } else {
54405d3dc29Sdan    append order " 3 DESC"
54505d3dc29Sdan  }
54605d3dc29Sdan
54705d3dc29Sdan  db eval "
54805d3dc29Sdan    WITH flat(fid, depth, p) AS (
54905d3dc29Sdan        SELECT id, 1, '/' || payload FROM tree WHERE parentid IS NULL
55005d3dc29Sdan        UNION ALL
55105d3dc29Sdan        SELECT id, depth+1, p||'/'||payload FROM flat, tree WHERE parentid=fid
55205d3dc29Sdan        $order
55305d3dc29Sdan    )
55405d3dc29Sdan    SELECT p FROM flat;
55505d3dc29Sdan  "
55605d3dc29Sdan}
55705d3dc29Sdan
55805d3dc29Sdaninsert_into_tree {
55905d3dc29Sdan  /a/b
56005d3dc29Sdan  /a/b/c
56105d3dc29Sdan  /a/d
56205d3dc29Sdan  /a/d/e
56305d3dc29Sdan  /a/d/f
56405d3dc29Sdan  /g/h
56505d3dc29Sdan}
56605d3dc29Sdan
56705d3dc29Sdan# Breadth first, siblings in ascending order.
56805d3dc29Sdan#
56905d3dc29Sdando_test 10.3 {
57005d3dc29Sdan  scan_tree 0 0
57105d3dc29Sdan} [list {*}{
57205d3dc29Sdan  /a /g
57305d3dc29Sdan  /a/b /a/d /g/h
57405d3dc29Sdan  /a/b/c /a/d/e /a/d/f
57505d3dc29Sdan}]
57605d3dc29Sdan
57705d3dc29Sdan# Depth first, siblings in ascending order.
57805d3dc29Sdan#
57905d3dc29Sdando_test 10.4 {
58005d3dc29Sdan  scan_tree 1 0
58105d3dc29Sdan} [list {*}{
58205d3dc29Sdan  /a /a/b /a/b/c
58305d3dc29Sdan     /a/d /a/d/e
58405d3dc29Sdan          /a/d/f
58505d3dc29Sdan  /g /g/h
58605d3dc29Sdan}]
58705d3dc29Sdan
58805d3dc29Sdan# Breadth first, siblings in descending order.
58905d3dc29Sdan#
59005d3dc29Sdando_test 10.5 {
59105d3dc29Sdan  scan_tree 0 1
59205d3dc29Sdan} [list {*}{
59305d3dc29Sdan  /g /a
59405d3dc29Sdan  /g/h /a/d /a/b
59505d3dc29Sdan  /a/d/f /a/d/e /a/b/c
59605d3dc29Sdan}]
59705d3dc29Sdan
59805d3dc29Sdan# Depth first, siblings in ascending order.
59905d3dc29Sdan#
60005d3dc29Sdando_test 10.6 {
60105d3dc29Sdan  scan_tree 1 1
60205d3dc29Sdan} [list {*}{
60305d3dc29Sdan  /g /g/h
60405d3dc29Sdan  /a /a/d /a/d/f
60505d3dc29Sdan          /a/d/e
60605d3dc29Sdan     /a/b /a/b/c
60705d3dc29Sdan}]
60805d3dc29Sdan
609b090352bSdrh
61053bed45eSdan# Test name resolution in ORDER BY clauses.
61153bed45eSdan#
61253bed45eSdando_catchsql_test 10.7.1 {
61353bed45eSdan  WITH t(a) AS (
61453bed45eSdan    SELECT 1 AS b UNION ALL SELECT a+1 AS c FROM t WHERE a<5 ORDER BY a
61553bed45eSdan  )
61653bed45eSdan  SELECT * FROM t
61753bed45eSdan} {1 {1st ORDER BY term does not match any column in the result set}}
61853bed45eSdando_execsql_test 10.7.2 {
61953bed45eSdan  WITH t(a) AS (
62053bed45eSdan    SELECT 1 AS b UNION ALL SELECT a+1 AS c FROM t WHERE a<5 ORDER BY b
62153bed45eSdan  )
62253bed45eSdan  SELECT * FROM t
62353bed45eSdan} {1 2 3 4 5}
62453bed45eSdando_execsql_test 10.7.3 {
62553bed45eSdan  WITH t(a) AS (
62653bed45eSdan    SELECT 1 AS b UNION ALL SELECT a+1 AS c FROM t WHERE a<5 ORDER BY c
62753bed45eSdan  )
62853bed45eSdan  SELECT * FROM t
62953bed45eSdan} {1 2 3 4 5}
63053bed45eSdan
63153bed45eSdan# Test COLLATE clauses attached to ORDER BY.
63253bed45eSdan#
63353bed45eSdaninsert_into_tree {
63453bed45eSdan  /a/b
63553bed45eSdan  /a/C
63653bed45eSdan  /a/d
63753bed45eSdan  /B/e
63853bed45eSdan  /B/F
63953bed45eSdan  /B/g
64053bed45eSdan  /c/h
64153bed45eSdan  /c/I
64253bed45eSdan  /c/j
64353bed45eSdan}
64453bed45eSdan
64553bed45eSdando_execsql_test 10.8.1 {
64653bed45eSdan  WITH flat(fid, depth, p) AS (
64753bed45eSdan    SELECT id, 1, '/' || payload FROM tree WHERE parentid IS NULL
64853bed45eSdan    UNION ALL
64953bed45eSdan    SELECT id, depth+1, p||'/'||payload FROM flat, tree WHERE parentid=fid
65053bed45eSdan    ORDER BY 2, 3 COLLATE nocase
65153bed45eSdan  )
65253bed45eSdan  SELECT p FROM flat;
65353bed45eSdan} {
65453bed45eSdan  /a /B /c
65553bed45eSdan  /a/b /a/C /a/d /B/e /B/F /B/g /c/h /c/I /c/j
65653bed45eSdan}
65753bed45eSdando_execsql_test 10.8.2 {
65853bed45eSdan  WITH flat(fid, depth, p) AS (
65953bed45eSdan      SELECT id, 1, ('/' || payload) COLLATE nocase
66053bed45eSdan      FROM tree WHERE parentid IS NULL
66153bed45eSdan    UNION ALL
66253bed45eSdan      SELECT id, depth+1, (p||'/'||payload)
66353bed45eSdan      FROM flat, tree WHERE parentid=fid
66453bed45eSdan    ORDER BY 2, 3
66553bed45eSdan  )
66653bed45eSdan  SELECT p FROM flat;
66753bed45eSdan} {
66853bed45eSdan  /a /B /c
66953bed45eSdan  /a/b /a/C /a/d /B/e /B/F /B/g /c/h /c/I /c/j
67053bed45eSdan}
67153bed45eSdan
67253bed45eSdando_execsql_test 10.8.3 {
67353bed45eSdan  WITH flat(fid, depth, p) AS (
67453bed45eSdan      SELECT id, 1, ('/' || payload)
67553bed45eSdan      FROM tree WHERE parentid IS NULL
67653bed45eSdan    UNION ALL
67753bed45eSdan      SELECT id, depth+1, (p||'/'||payload) COLLATE nocase
67853bed45eSdan      FROM flat, tree WHERE parentid=fid
67953bed45eSdan    ORDER BY 2, 3
68053bed45eSdan  )
68153bed45eSdan  SELECT p FROM flat;
68253bed45eSdan} {
68353bed45eSdan  /a /B /c
68453bed45eSdan  /a/b /a/C /a/d /B/e /B/F /B/g /c/h /c/I /c/j
68553bed45eSdan}
68653bed45eSdan
68753bed45eSdando_execsql_test 10.8.4.1 {
68853bed45eSdan  CREATE TABLE tst(a,b);
68953bed45eSdan  INSERT INTO tst VALUES('a', 'A');
69053bed45eSdan  INSERT INTO tst VALUES('b', 'B');
69153bed45eSdan  INSERT INTO tst VALUES('c', 'C');
69253bed45eSdan  SELECT a COLLATE nocase FROM tst UNION ALL SELECT b FROM tst ORDER BY 1;
69353bed45eSdan} {a A b B c C}
69453bed45eSdando_execsql_test 10.8.4.2 {
69553bed45eSdan  SELECT a FROM tst UNION ALL SELECT b COLLATE nocase FROM tst ORDER BY 1;
69653bed45eSdan} {A B C a b c}
69753bed45eSdando_execsql_test 10.8.4.3 {
69853bed45eSdan  SELECT a||'' FROM tst UNION ALL SELECT b COLLATE nocase FROM tst ORDER BY 1;
69953bed45eSdan} {a A b B c C}
70053bed45eSdan
701b090352bSdrh# Test cases to illustrate on the ORDER BY clause on a recursive query can be
702b090352bSdrh# used to control depth-first versus breath-first search in a tree.
703b090352bSdrh#
70405d3dc29Sdando_execsql_test 11.1 {
705b090352bSdrh  CREATE TABLE org(
706b090352bSdrh    name TEXT PRIMARY KEY,
707b090352bSdrh    boss TEXT REFERENCES org
708b090352bSdrh  ) WITHOUT ROWID;
709b090352bSdrh  INSERT INTO org VALUES('Alice',NULL);
710b090352bSdrh  INSERT INTO org VALUES('Bob','Alice');
711b090352bSdrh  INSERT INTO org VALUES('Cindy','Alice');
712b090352bSdrh  INSERT INTO org VALUES('Dave','Bob');
713b090352bSdrh  INSERT INTO org VALUES('Emma','Bob');
714b090352bSdrh  INSERT INTO org VALUES('Fred','Cindy');
715b090352bSdrh  INSERT INTO org VALUES('Gail','Cindy');
716b090352bSdrh  INSERT INTO org VALUES('Harry','Dave');
717b090352bSdrh  INSERT INTO org VALUES('Ingrid','Dave');
718b090352bSdrh  INSERT INTO org VALUES('Jim','Emma');
719b090352bSdrh  INSERT INTO org VALUES('Kate','Emma');
720b090352bSdrh  INSERT INTO org VALUES('Lanny','Fred');
721b090352bSdrh  INSERT INTO org VALUES('Mary','Fred');
722b090352bSdrh  INSERT INTO org VALUES('Noland','Gail');
723b090352bSdrh  INSERT INTO org VALUES('Olivia','Gail');
724b090352bSdrh  -- The above are all under Alice.  Add a few more records for people
725b090352bSdrh  -- not in Alice's group, just to prove that they won't be selected.
726b090352bSdrh  INSERT INTO org VALUES('Xaviar',NULL);
727b090352bSdrh  INSERT INTO org VALUES('Xia','Xaviar');
728b090352bSdrh  INSERT INTO org VALUES('Xerxes','Xaviar');
729b090352bSdrh  INSERT INTO org VALUES('Xena','Xia');
730b090352bSdrh  -- Find all members of Alice's group, breath-first order
731b090352bSdrh  WITH RECURSIVE
732b090352bSdrh    under_alice(name,level) AS (
733b090352bSdrh       VALUES('Alice','0')
734b090352bSdrh       UNION ALL
735b090352bSdrh       SELECT org.name, under_alice.level+1
736b090352bSdrh         FROM org, under_alice
737b090352bSdrh        WHERE org.boss=under_alice.name
738b090352bSdrh        ORDER BY 2
739b090352bSdrh    )
740b090352bSdrh  SELECT group_concat(substr('...............',1,level*3) || name,x'0a')
741b090352bSdrh    FROM under_alice;
742b090352bSdrh} {{Alice
743b090352bSdrh...Bob
744b090352bSdrh...Cindy
745b090352bSdrh......Dave
746b090352bSdrh......Emma
747b090352bSdrh......Fred
748b090352bSdrh......Gail
749b090352bSdrh.........Harry
750b090352bSdrh.........Ingrid
751b090352bSdrh.........Jim
752b090352bSdrh.........Kate
753b090352bSdrh.........Lanny
754b090352bSdrh.........Mary
755b090352bSdrh.........Noland
756b090352bSdrh.........Olivia}}
757b090352bSdrh
758b090352bSdrh# The previous query used "ORDER BY level" to yield a breath-first search.
759b090352bSdrh# Change that to "ORDER BY level DESC" for a depth-first search.
760b090352bSdrh#
76105d3dc29Sdando_execsql_test 11.2 {
762b090352bSdrh  WITH RECURSIVE
763b090352bSdrh    under_alice(name,level) AS (
764b090352bSdrh       VALUES('Alice','0')
765b090352bSdrh       UNION ALL
766b090352bSdrh       SELECT org.name, under_alice.level+1
767b090352bSdrh         FROM org, under_alice
768b090352bSdrh        WHERE org.boss=under_alice.name
769b090352bSdrh        ORDER BY 2 DESC
770b090352bSdrh    )
771b090352bSdrh  SELECT group_concat(substr('...............',1,level*3) || name,x'0a')
772b090352bSdrh    FROM under_alice;
773b090352bSdrh} {{Alice
774b090352bSdrh...Bob
775b090352bSdrh......Dave
776b090352bSdrh.........Harry
777b090352bSdrh.........Ingrid
778b090352bSdrh......Emma
779b090352bSdrh.........Jim
780b090352bSdrh.........Kate
781b090352bSdrh...Cindy
782b090352bSdrh......Fred
783b090352bSdrh.........Lanny
784b090352bSdrh.........Mary
785b090352bSdrh......Gail
786b090352bSdrh.........Noland
787b090352bSdrh.........Olivia}}
788b090352bSdrh
789b090352bSdrh# Without an ORDER BY clause, the recursive query should use a FIFO,
790b090352bSdrh# resulting in a breath-first search.
791b090352bSdrh#
79205d3dc29Sdando_execsql_test 11.3 {
793b090352bSdrh  WITH RECURSIVE
794b090352bSdrh    under_alice(name,level) AS (
795b090352bSdrh       VALUES('Alice','0')
796b090352bSdrh       UNION ALL
797b090352bSdrh       SELECT org.name, under_alice.level+1
798b090352bSdrh         FROM org, under_alice
799b090352bSdrh        WHERE org.boss=under_alice.name
800b090352bSdrh    )
801b090352bSdrh  SELECT group_concat(substr('...............',1,level*3) || name,x'0a')
802b090352bSdrh    FROM under_alice;
803b090352bSdrh} {{Alice
804b090352bSdrh...Bob
805b090352bSdrh...Cindy
806b090352bSdrh......Dave
807b090352bSdrh......Emma
808b090352bSdrh......Fred
809b090352bSdrh......Gail
810b090352bSdrh.........Harry
811b090352bSdrh.........Ingrid
812b090352bSdrh.........Jim
813b090352bSdrh.........Kate
814b090352bSdrh.........Lanny
815b090352bSdrh.........Mary
816b090352bSdrh.........Noland
817b090352bSdrh.........Olivia}}
818b090352bSdrh
819d227a291Sdrh#--------------------------------------------------------------------------
820d227a291Sdrh# Ticket [31a19d11b97088296ac104aaff113a9790394927] (2014-02-09)
821d227a291Sdrh# Name resolution issue with compound SELECTs and Common Table Expressions
822d227a291Sdrh#
823d227a291Sdrhdo_execsql_test 12.1 {
824d227a291SdrhWITH RECURSIVE
825d227a291Sdrh  t1(x) AS (VALUES(2) UNION ALL SELECT x+2 FROM t1 WHERE x<20),
826d227a291Sdrh  t2(y) AS (VALUES(3) UNION ALL SELECT y+3 FROM t2 WHERE y<20)
827d227a291SdrhSELECT x FROM t1 EXCEPT SELECT y FROM t2 ORDER BY 1;
828d227a291Sdrh} {2 4 8 10 14 16 20}
82905d3dc29Sdan
8308f9d0b2bSdrh# 2015-03-21
8318f9d0b2bSdrh# Column wildcards on the LHS of a recursive table expression
8328f9d0b2bSdrh#
8338f9d0b2bSdrhdo_catchsql_test 13.1 {
8348f9d0b2bSdrh  WITH RECURSIVE c(i) AS (SELECT * UNION ALL SELECT i+1 FROM c WHERE i<10)
8358f9d0b2bSdrh  SELECT i FROM c;
8368f9d0b2bSdrh} {1 {no tables specified}}
8378f9d0b2bSdrhdo_catchsql_test 13.2 {
8388f9d0b2bSdrh  WITH RECURSIVE c(i) AS (SELECT 5,* UNION ALL SELECT i+1 FROM c WHERE i<10)
8398f9d0b2bSdrh  SELECT i FROM c;
8408f9d0b2bSdrh} {1 {no tables specified}}
8418f9d0b2bSdrhdo_catchsql_test 13.3 {
8428f9d0b2bSdrh  WITH RECURSIVE c(i,j) AS (SELECT 5,* UNION ALL SELECT i+1,11 FROM c WHERE i<10)
8438f9d0b2bSdrh  SELECT i FROM c;
8448f9d0b2bSdrh} {1 {table c has 1 values for 2 columns}}
845d227a291Sdrh
846f932f714Sdrh# 2015-04-12
847f932f714Sdrh#
848f932f714Sdrhdo_execsql_test 14.1 {
849f932f714Sdrh  WITH x AS (SELECT * FROM t) SELECT 0 EXCEPT SELECT 0 ORDER BY 1 COLLATE binary;
850f932f714Sdrh} {}
851f932f714Sdrh
852fccda8a1Sdrh# 2015-05-27:  Do not allow rowid usage within a CTE
853fccda8a1Sdrh#
854fccda8a1Sdrhdo_catchsql_test 15.1 {
855fccda8a1Sdrh  WITH RECURSIVE
856fccda8a1Sdrh    d(x) AS (VALUES(1) UNION ALL SELECT rowid+1 FROM d WHERE rowid<10)
857fccda8a1Sdrh  SELECT x FROM d;
858fccda8a1Sdrh} {1 {no such column: rowid}}
859fccda8a1Sdrh
860b63ce02fSdrh# 2015-07-05:  Do not allow aggregate recursive queries
861b63ce02fSdrh#
862b63ce02fSdrhdo_catchsql_test 16.1 {
863b63ce02fSdrh  WITH RECURSIVE
864b63ce02fSdrh    i(x) AS (VALUES(1) UNION SELECT count(*) FROM i)
865b63ce02fSdrh  SELECT * FROM i;
866b63ce02fSdrh} {1 {recursive aggregate queries not supported}}
867fccda8a1Sdrh
8686afa35c9Sdan# Or window-function recursive queries. Ticket e8275b41.
8696afa35c9Sdan#
8706afa35c9Sdanifcapable windowfunc {
8716afa35c9Sdan  do_catchsql_test 16.2 {
8726afa35c9Sdan    WITH RECURSIVE
8736afa35c9Sdan      i(x) AS (VALUES(1) UNION SELECT count(*) OVER () FROM i)
8746afa35c9Sdan      SELECT * FROM i;
8756afa35c9Sdan  } {1 {cannot use window functions in recursive queries}}
8766afa35c9Sdan  do_catchsql_test 16.3 {
8776afa35c9Sdan    WITH RECURSIVE
8786afa35c9Sdan      t(id, parent) AS (VALUES(1,2)),
8796afa35c9Sdan      q(id, parent, rn) AS (
8806afa35c9Sdan          VALUES(1,2,3)
8816afa35c9Sdan          UNION ALL
8826afa35c9Sdan          SELECT t.*, ROW_NUMBER() OVER (ORDER BY t.id) AS rn
8836afa35c9Sdan          FROM q JOIN t ON t.parent = q.id
8846afa35c9Sdan          )
8856afa35c9Sdan        SELECT * FROM q;
8866afa35c9Sdan  } {1 {cannot use window functions in recursive queries}}
8876afa35c9Sdan}
8886afa35c9Sdan
889fe88fbfcSdan#-------------------------------------------------------------------------
890fe88fbfcSdando_execsql_test 17.1 {
891fe88fbfcSdan  WITH x(a) AS (
892fe88fbfcSdan    WITH y(b) AS (SELECT 10)
893fe88fbfcSdan    SELECT 9 UNION ALL SELECT * FROM y
894fe88fbfcSdan  )
895fe88fbfcSdan  SELECT * FROM x
896fe88fbfcSdan} {9 10}
897fe88fbfcSdan
898fe88fbfcSdando_execsql_test 17.2 {
899fe88fbfcSdan  WITH x AS (
900fe88fbfcSdan    WITH y(b) AS (SELECT 10)
901fe88fbfcSdan    SELECT * FROM y UNION ALL SELECT * FROM y
902fe88fbfcSdan  )
903fe88fbfcSdan  SELECT * FROM x
904fe88fbfcSdan} {10 10}
905fe88fbfcSdan
906fe88fbfcSdando_test 17.2 {
907fe88fbfcSdan  db eval {
908fe88fbfcSdan    WITH x AS (
909fe88fbfcSdan        WITH y(b) AS (SELECT 10)
910fe88fbfcSdan        SELECT * FROM y UNION ALL SELECT * FROM y
911fe88fbfcSdan    )
912fe88fbfcSdan    SELECT * FROM x
913fe88fbfcSdan  } A {
914fe88fbfcSdan    # no op
915fe88fbfcSdan  }
916fe88fbfcSdan  set A(*)
917fe88fbfcSdan} {b}
918fe88fbfcSdan
919fe88fbfcSdando_catchsql_test 17.3 {
920fe88fbfcSdan  WITH i AS (
921fe88fbfcSdan    WITH j AS (SELECT 5)
922fe88fbfcSdan    SELECT 5 FROM i UNION SELECT 8 FROM i
923fe88fbfcSdan  )
924fe88fbfcSdan  SELECT * FROM i;
925fe88fbfcSdan} {1 {circular reference: i}}
926fe88fbfcSdan
927fe88fbfcSdando_catchsql_test 17.4 {
928fe88fbfcSdan  WITH i AS (
929fe88fbfcSdan    WITH j AS (SELECT 5)
930fe88fbfcSdan    SELECT 5 FROM t1 UNION SELECT 8 FROM t11
931fe88fbfcSdan  )
932fe88fbfcSdan  SELECT * FROM i;
933fe88fbfcSdan} {1 {no such table: t11}}
934fe88fbfcSdan
935fe88fbfcSdando_execsql_test 17.5 {
936fe88fbfcSdan  WITH
937fe88fbfcSdan  x1 AS (SELECT 10),
938fe88fbfcSdan  x2 AS (SELECT * FROM x1),
939fe88fbfcSdan  x3 AS (
940fe88fbfcSdan    WITH x1 AS (SELECT 11)
941fe88fbfcSdan    SELECT * FROM x2 UNION ALL SELECT * FROM x2
942fe88fbfcSdan  )
943fe88fbfcSdan  SELECT * FROM x3;
944fe88fbfcSdan} {10 10}
945fe88fbfcSdan
946fe88fbfcSdando_execsql_test 17.6 {
947fe88fbfcSdan  WITH
948fe88fbfcSdan  x1 AS (SELECT 10),
949fe88fbfcSdan  x2 AS (SELECT * FROM x1),
950fe88fbfcSdan  x3 AS (
951fe88fbfcSdan    WITH x1 AS (SELECT 11)
952fe88fbfcSdan    SELECT * FROM x2 UNION ALL SELECT * FROM x1
953fe88fbfcSdan  )
954fe88fbfcSdan  SELECT * FROM x3;
955fe88fbfcSdan} {10 11}
956fe88fbfcSdan
957fe88fbfcSdando_execsql_test 17.7 {
958fe88fbfcSdan  WITH
959fe88fbfcSdan  x1 AS (SELECT 10),
960fe88fbfcSdan  x2 AS (SELECT * FROM x1),
961fe88fbfcSdan  x3 AS (
962fe88fbfcSdan    WITH
963fe88fbfcSdan      x1 AS ( SELECT 11 ),
964fe88fbfcSdan      x4 AS ( SELECT * FROM x2 )
965fe88fbfcSdan    SELECT * FROM x4 UNION ALL SELECT * FROM x1
966fe88fbfcSdan  )
967fe88fbfcSdan  SELECT * FROM x3;
968fe88fbfcSdan} {10 11}
969fe88fbfcSdan
970fe88fbfcSdando_execsql_test 17.8 {
971fe88fbfcSdan  WITH
972fe88fbfcSdan  x1 AS (SELECT 10),
973fe88fbfcSdan  x2 AS (SELECT * FROM x1),
974fe88fbfcSdan  x3 AS (
975fe88fbfcSdan    WITH
976fe88fbfcSdan      x1 AS ( SELECT 11 ),
977fe88fbfcSdan      x4 AS ( SELECT * FROM x2 )
978fe88fbfcSdan    SELECT * FROM x4 UNION ALL SELECT * FROM x1
979fe88fbfcSdan  )
980fe88fbfcSdan  SELECT * FROM x3;
981fe88fbfcSdan} {10 11}
982fe88fbfcSdan
983fe88fbfcSdando_execsql_test 17.9 {
984fe88fbfcSdan  WITH
985fe88fbfcSdan  x1 AS (SELECT 10),
986fe88fbfcSdan  x2 AS (SELECT 11),
987fe88fbfcSdan  x3 AS (
988fe88fbfcSdan    SELECT * FROM x1 UNION ALL SELECT * FROM x2
989fe88fbfcSdan  ),
990fe88fbfcSdan  x4 AS (
991fe88fbfcSdan    WITH
992fe88fbfcSdan    x1 AS (SELECT 12),
993fe88fbfcSdan    x2 AS (SELECT 13)
994fe88fbfcSdan    SELECT * FROM x3
995fe88fbfcSdan  )
996fe88fbfcSdan  SELECT * FROM x4;
997fe88fbfcSdan} {10 11}
998fe88fbfcSdan
999b1d6b536Sdan# Added to test a fix to a faulty assert() discovered by libFuzzer.
1000b1d6b536Sdan#
1001b1d6b536Sdando_execsql_test 18.1 {
1002b1d6b536Sdan  WITH xyz(x) AS (VALUES(NULL) UNION SELECT round(1<x) FROM xyz ORDER BY 1)
1003b1d6b536Sdan  SELECT quote(x) FROM xyz;
1004b1d6b536Sdan} {NULL}
1005b1d6b536Sdando_execsql_test 18.2 {
1006b1d6b536Sdan  WITH xyz(x) AS (
1007b1d6b536Sdan    SELECT printf('%d', 5) * NULL
1008b1d6b536Sdan    UNION SELECT round(1<1+x)
1009b1d6b536Sdan    FROM xyz ORDER BY 1
1010b1d6b536Sdan  )
1011b1d6b536Sdan  SELECT 1 FROM xyz;
1012b1d6b536Sdan} 1
1013b1d6b536Sdan
1014d8a29566Sdrh# EXPLAIN QUERY PLAN on a self-join of a CTE
1015d8a29566Sdrh#
1016b3f0276bSdrhdo_execsql_test 19.1a {
1017d8a29566Sdrh  DROP TABLE IF EXISTS t1;
1018d8a29566Sdrh  CREATE TABLE t1(x);
1019b3f0276bSdrh}
1020b3f0276bSdrhdo_eqp_test 19.1b {
1021d8a29566Sdrh  WITH
1022d8a29566Sdrh    x1(a) AS (values(100))
1023d8a29566Sdrh  INSERT INTO t1(x)
1024d8a29566Sdrh    SELECT * FROM (WITH x2(y) AS (SELECT * FROM x1) SELECT y+a FROM x1, x2);
1025d8a29566Sdrh  SELECT * FROM t1;
1026b3f0276bSdrh} {
1027b3f0276bSdrh  QUERY PLAN
10288210233cSdrh  |--MATERIALIZE x1
1029fa16f5d9Sdrh  |  `--SCAN CONSTANT ROW
10308210233cSdrh  |--SCAN x1
10318210233cSdrh  `--SCAN x1
1032b3f0276bSdrh}
1033d8a29566Sdrh
10346d6e76f7Sdrh# 2017-10-28.
10356d6e76f7Sdrh# See check-in https://sqlite.org/src/info/0926df095faf72c2
10366d6e76f7Sdrh# Tried to optimize co-routine processing by changing a Copy opcode
10376d6e76f7Sdrh# into SCopy.  But OSSFuzz found two (similar) cases where that optimization
10386d6e76f7Sdrh# does not work.
10396d6e76f7Sdrh#
10406d6e76f7Sdrhdo_execsql_test 20.1 {
10416d6e76f7Sdrh  WITH c(i)AS(VALUES(9)UNION SELECT~i FROM c)SELECT max(5)>i fROM c;
10426d6e76f7Sdrh} {0}
10436d6e76f7Sdrhdo_execsql_test 20.2 {
10446d6e76f7Sdrh  WITH c(i)AS(VALUES(5)UNIoN SELECT 0)SELECT min(1)-i fROM c;
10456d6e76f7Sdrh} {1}
1046b1d6b536Sdan
1047bdefaf08Sdrh# 2018-12-26
1048bdefaf08Sdrh# Two different CTE tables with the same name appear in within a single FROM
1049bdefaf08Sdrh# clause due to the query-flattener optimization.  make sure this does not cause
1050bdefaf08Sdrh# problems.  This problem was discovered by Matt Denton.
1051bdefaf08Sdrh#
1052bdefaf08Sdrhdo_execsql_test 21.1 {
1053bdefaf08Sdrh   WITH RECURSIVE t21(a,b) AS (
1054bdefaf08Sdrh    WITH t21(x) AS (VALUES(1))
1055bdefaf08Sdrh    SELECT x, x FROM t21 ORDER BY 1
1056bdefaf08Sdrh  )
1057bdefaf08Sdrh  SELECT * FROM t21 AS tA, t21 AS tB
1058bdefaf08Sdrh} {1 1 1 1}
1059375afb8bSdrhdo_execsql_test 21.1b {
1060375afb8bSdrh   /* This variant from chromium bug 922312 on 2019-01-16 */
1061375afb8bSdrh   WITH RECURSIVE t21(a,b) AS (
1062375afb8bSdrh    WITH t21(x) AS (VALUES(1))
1063375afb8bSdrh    SELECT x, x FROM t21 ORDER BY 1 LIMIT 5
1064375afb8bSdrh  )
1065375afb8bSdrh  SELECT * FROM t21 AS tA, t21 AS tB
1066375afb8bSdrh} {1 1 1 1}
1067bdefaf08Sdrhdo_execsql_test 21.2 {
1068bdefaf08Sdrh  SELECT printf('',
1069bdefaf08Sdrh     EXISTS (WITH RECURSIVE Table0 AS (WITH Table0 AS (SELECT DISTINCT 1)
1070bdefaf08Sdrh                                       SELECT *, * FROM Table0 ORDER BY 1 DESC)
1071bdefaf08Sdrh             SELECT * FROM Table0  NATURAL JOIN  Table0));
1072bdefaf08Sdrh} {{}}
1073bdefaf08Sdrh
10740ad7aa81Sdrh# 2019-01-17
10750ad7aa81Sdrh# Make sure crazy nexted CTE joins terminate with an error quickly.
10760ad7aa81Sdrh#
10770ad7aa81Sdrhdo_catchsql_test 22.1 {
1078*67f70beaSdrh  WITH RECURSIVE c AS NOT MATERIALIZED (
1079*67f70beaSdrh     WITH RECURSIVE c AS NOT MATERIALIZED (
1080*67f70beaSdrh        WITH RECURSIVE c AS NOT MATERIALIZED (
1081*67f70beaSdrh           WITH RECURSIVE c AS NOT MATERIALIZED (
10820ad7aa81Sdrh               WITH  c AS (VALUES(0))
10830ad7aa81Sdrh               SELECT 1 FROM c LEFT JOIN c ON ltrim(1)
10840ad7aa81Sdrh           )
10850ad7aa81Sdrh           SELECT 1 FROM c,c,c,c,c,c,c,c,c
10860ad7aa81Sdrh        )
10870ad7aa81Sdrh        SELECT  2 FROM c,c,c,c,c,c,c,c,c
10880ad7aa81Sdrh     )
10890ad7aa81Sdrh     SELECT 3 FROM c,c,c,c,c,c,c,c,c
10900ad7aa81Sdrh  )
10910ad7aa81Sdrh  SELECT 4 FROM c,c,c,c,c,c,c,c,c;
10924acd754cSdrh} {1 {too many FROM clause terms, max: 200}}
10930ad7aa81Sdrh
109459145813Sdrh# 2019-05-22
109559145813Sdrh# ticket https://www.sqlite.org/src/tktview/ce823231949d3abf42453c8f20
109659145813Sdrh#
109759145813Sdrhsqlite3 db :memory:
109859145813Sdrhdo_execsql_test 23.1 {
109959145813Sdrh  CREATE TABLE t1(id INTEGER NULL PRIMARY KEY, name Text);
110059145813Sdrh  INSERT INTO t1 VALUES (1, 'john');
110159145813Sdrh  INSERT INTO t1 VALUES (2, 'james');
110259145813Sdrh  INSERT INTO t1 VALUES (3, 'jingle');
110359145813Sdrh  INSERT INTO t1 VALUES (4, 'himer');
110459145813Sdrh  INSERT INTO t1 VALUES (5, 'smith');
110559145813Sdrh  CREATE VIEW v2 AS
110659145813Sdrh    WITH t4(Name) AS (VALUES ('A'), ('B'))
110759145813Sdrh    SELECT Name Name FROM t4;
110859145813Sdrh  CREATE VIEW v3 AS
110959145813Sdrh    WITH t4(Att, Val, Act) AS (VALUES
111059145813Sdrh      ('C', 'D', 'E'),
111159145813Sdrh      ('F', 'G', 'H')
111259145813Sdrh    )
111359145813Sdrh    SELECT D.Id Id, P.Name Protocol, T.Att Att, T.Val Val, T.Act Act
111459145813Sdrh    FROM t1 D
111559145813Sdrh    CROSS JOIN v2 P
111659145813Sdrh    CROSS JOIN t4 T;
111759145813Sdrh  SELECT * FROM v3;
111859145813Sdrh} {1 A C D E 1 A F G H 1 B C D E 1 B F G H 2 A C D E 2 A F G H 2 B C D E 2 B F G H 3 A C D E 3 A F G H 3 B C D E 3 B F G H 4 A C D E 4 A F G H 4 B C D E 4 B F G H 5 A C D E 5 A F G H 5 B C D E 5 B F G H}
111959145813Sdrh
1120c542fa85Sdan#-------------------------------------------------------------------------
1121c542fa85Sdanreset_db
1122c542fa85Sdando_execsql_test 24.1 {
1123c542fa85Sdan  CREATE TABLE t1(a, b, c);
1124c542fa85Sdan  CREATE VIEW v1 AS SELECT max(a), min(b) FROM t1 GROUP BY c;
1125c542fa85Sdan}
1126c542fa85Sdando_test 24.1 {
1127c542fa85Sdan  set program [db eval {EXPLAIN SELECT 1 FROM v1,v1,v1}]
1128c542fa85Sdan  expr [lsearch $program OpenDup]>0
1129c542fa85Sdan} {1}
1130c542fa85Sdando_execsql_test 24.2 {
1131c542fa85Sdan  ATTACH "" AS aux;
1132c542fa85Sdan  CREATE VIEW aux.v3 AS VALUES(1);
1133c542fa85Sdan  CREATE VIEW main.v3 AS VALUES(3);
1134c542fa85Sdan
1135c542fa85Sdan  CREATE VIEW aux.v2 AS SELECT * FROM v3;
1136c542fa85Sdan  CREATE VIEW main.v2 AS SELECT * FROM v3;
1137c542fa85Sdan
1138c542fa85Sdan  SELECT * FROM main.v2 AS a, aux.v2 AS b, aux.v2 AS c, main.v2 AS d;
1139c542fa85Sdan} {
1140c542fa85Sdan  3 1 1 3
1141c542fa85Sdan}
1142c542fa85Sdan
11430cbec59cSdrh# 2020-01-02 chromium ticket 1033461
11440cbec59cSdrh# Do not allow the generated name of a CTE be "true" or "false" as
11450cbec59cSdrh# such a label might be later confused for the boolean literals of
11460cbec59cSdrh# the same name, causing inconsistencies in the abstract syntax
11470cbec59cSdrh# tree.  This problem first arose in version 3.23.0 when SQLite
11480cbec59cSdrh# began recognizing "true" and "false" as boolean literals, but also
11490cbec59cSdrh# had to continue to recognize "true" and "false" as identifiers for
11500cbec59cSdrh# backwards compatibility.
11510cbec59cSdrh#
1152a76b7f52Sdrhforeach {id dual} {
1153a76b7f52Sdrh  1  {CREATE TABLE dual AS SELECT 'X' AS dummy}
1154a76b7f52Sdrh  2  {CREATE TEMP TABLE dual AS SELECT 'X' AS dummy}
1155a76b7f52Sdrh  3  {CREATE VIEW dual(dummy) AS VALUES('X')}
1156a76b7f52Sdrh  4  {CREATE TEMP VIEW dual(dummy) AS VALUES('X')}
1157a76b7f52Sdrh} {
11580cbec59cSdrh  reset_db
1159a76b7f52Sdrh  db eval $dual
1160a76b7f52Sdrh  do_execsql_test 25.$id {
11610cbec59cSdrh    WITH cte1 AS (
11620cbec59cSdrh      SELECT TRUE, (
11630cbec59cSdrh        WITH cte2 AS (SELECT avg(DISTINCT TRUE) FROM dual)
11640cbec59cSdrh        SELECT 2571 FROM cte2
11650cbec59cSdrh      ) AS subquery1
11660cbec59cSdrh      FROM dual
11670cbec59cSdrh      GROUP BY 1
11680cbec59cSdrh    )
11690cbec59cSdrh    SELECT (SELECT 1324 FROM cte1) FROM cte1;
11700cbec59cSdrh  } {1324}
1171a76b7f52Sdrh}
11720cbec59cSdrh
117370a32703Sdando_catchsql_test 26.0 {
117470a32703Sdan  WITH i(x) AS (
117570a32703Sdan    VALUES(1) UNION ALL SELECT x+1 FRO, a.b,O. * ,I¬i O, a.b,O. * ORDER BY 1
117670a32703Sdan  )
117770a32703Sdan  SELECT x,O. * O FROM i ¬I,I? 10;
117870a32703Sdan} {1 {near "O": syntax error}}
117970a32703Sdan
1180f1ea4255Sdrh# 2020-09-17 ticket c51489c3b8f919c5
1181f1ea4255Sdrh# DISTINCT cannot be ignored in a UNION ALL recursive CTE
1182f1ea4255Sdrh#
1183f1ea4255Sdrhreset_db
1184f1ea4255Sdrhdo_execsql_test 26.1 {
1185f1ea4255Sdrh  CREATE TABLE t (label VARCHAR(10), step INTEGER);
1186f1ea4255Sdrh  INSERT INTO T VALUES('a', 1);
1187f1ea4255Sdrh  INSERT INTO T VALUES('a', 1);
1188f1ea4255Sdrh  INSERT INTO T VALUES('b', 1);
1189f1ea4255Sdrh  WITH RECURSIVE cte(label, step) AS (
1190f1ea4255Sdrh      SELECT DISTINCT * FROM t
1191f1ea4255Sdrh    UNION ALL
1192f1ea4255Sdrh      SELECT label, step + 1 FROM cte WHERE step < 3
1193f1ea4255Sdrh  )
1194f1ea4255Sdrh  SELECT * FROM cte ORDER BY +label, +step;
1195f1ea4255Sdrh} {a 1 a 2 a 3 b 1 b 2 b 3}
1196f1ea4255Sdrhdo_execsql_test 26.2 {
1197f1ea4255Sdrh  WITH RECURSIVE cte(label, step) AS (
1198f1ea4255Sdrh      SELECT * FROM t
1199f1ea4255Sdrh    UNION
1200f1ea4255Sdrh      SELECT label, step + 1 FROM cte WHERE step < 3
1201f1ea4255Sdrh  )
1202f1ea4255Sdrh  SELECT * FROM cte ORDER BY +label, +step;
1203f1ea4255Sdrh} {a 1 a 2 a 3 b 1 b 2 b 3}
1204f1ea4255Sdrhdo_execsql_test 26.3 {
1205f1ea4255Sdrh  CREATE TABLE tworow(x);
1206f1ea4255Sdrh  INSERT INTO tworow(x) VALUES(1),(2);
1207f1ea4255Sdrh  DELETE FROM t WHERE rowid=2;
1208f1ea4255Sdrh  WITH RECURSIVE cte(label, step) AS (
1209f1ea4255Sdrh      SELECT * FROM t
1210f1ea4255Sdrh    UNION ALL
1211f1ea4255Sdrh      SELECT DISTINCT label, step + 1 FROM cte, tworow WHERE step < 3
1212f1ea4255Sdrh  )
1213f1ea4255Sdrh  SELECT * FROM cte ORDER BY +label, +step;
1214f1ea4255Sdrh} {a 1 a 2 a 3 b 1 b 2 b 3}
1215f1ea4255Sdrh
1216cd1499f4Sdrh# 2021-05-20
1217cd1499f4Sdrh# forum post https://sqlite.org/forum/forumpost/8590e3f6dc
1218cd1499f4Sdrh#
1219cd1499f4Sdrhreset_db
1220cd1499f4Sdrhdo_execsql_test 27.1 {
1221cd1499f4Sdrh  CREATE TABLE t1(k);
1222cd1499f4Sdrh  CREATE TABLE log(k, cte_map, main_map);
1223cd1499f4Sdrh  CREATE TABLE map(k, v);
1224cd1499f4Sdrh  INSERT INTO map VALUES(1, 'main1'), (2, 'main2');
1225cd1499f4Sdrh
1226cd1499f4Sdrh  CREATE TRIGGER tr1 AFTER INSERT ON t1 BEGIN
1227cd1499f4Sdrh    INSERT INTO log
1228cd1499f4Sdrh        WITH map(k,v) AS (VALUES(1,'cte1'),(2,'cte2'))
1229cd1499f4Sdrh        SELECT
1230cd1499f4Sdrh          new.k,
1231cd1499f4Sdrh          (SELECT v FROM map WHERE k=new.k),
1232cd1499f4Sdrh          (SELECT v FROM main.map WHERE k=new.k);
1233cd1499f4Sdrh  END;
1234cd1499f4Sdrh
1235cd1499f4Sdrh  INSERT INTO t1 VALUES(1);
1236cd1499f4Sdrh  INSERT INTO t1 VALUES(2);
1237cd1499f4Sdrh  SELECT k, cte_map, main_map, '|' FROM log ORDER BY k;
1238cd1499f4Sdrh} {1 cte1 main1 | 2 cte2 main2 |}
1239cd1499f4Sdrh
1240d227a291Sdrhfinish_test
1241