xref: /sqlite-3.40.0/test/unionall.test (revision b6d91679)
1de9ed629Sdan# 2020-12-16
2de9ed629Sdan#
3de9ed629Sdan# The author disclaims copyright to this source code.  In place of
4de9ed629Sdan# a legal notice, here is a blessing:
5de9ed629Sdan#
6de9ed629Sdan#    May you do good and not evil.
7de9ed629Sdan#    May you find forgiveness for yourself and forgive others.
8de9ed629Sdan#    May you share freely, never taking more than you give.
9de9ed629Sdan#
10de9ed629Sdan#***********************************************************************
11de9ed629Sdan# This file implements regression tests for SQLite library.  The
12de9ed629Sdan# focus of this file is flattening UNION ALL sub-queries.
13de9ed629Sdan#
14de9ed629Sdan
15de9ed629Sdanset testdir [file dirname $argv0]
16de9ed629Sdansource $testdir/tester.tcl
17de9ed629Sdanset testprefix unionall
18de9ed629Sdan
19de9ed629Sdando_execsql_test 1.0 {
20de9ed629Sdan  CREATE TABLE t1_a(a INTEGER PRIMARY KEY, b TEXT);
21de9ed629Sdan  CREATE TABLE t1_b(c INTEGER PRIMARY KEY, d TEXT);
22de9ed629Sdan  CREATE TABLE t1_c(e INTEGER PRIMARY KEY, f TEXT);
23de9ed629Sdan
24de9ed629Sdan  INSERT INTO t1_a VALUES(1, 'one'), (4, 'four');
25de9ed629Sdan  INSERT INTO t1_b VALUES(2, 'two'), (5, 'five');
26de9ed629Sdan  INSERT INTO t1_c VALUES(3, 'three'), (6, 'six');
27de9ed629Sdan
28de9ed629Sdan  CREATE VIEW t1 AS
29de9ed629Sdan    SELECT a, b FROM t1_a   UNION ALL
30de9ed629Sdan    SELECT c, d FROM t1_b   UNION ALL
31de9ed629Sdan    SELECT e, f FROM t1_c;
32de9ed629Sdan
33de9ed629Sdan  CREATE TABLE i1(x);
34de9ed629Sdan  INSERT INTO i1 VALUES(2), (5), (6), (1);
35de9ed629Sdan}
36de9ed629Sdan
37de9ed629Sdando_execsql_test 1.1 {
38de9ed629Sdan  SELECT a, b FROM (
39de9ed629Sdan    SELECT a, b FROM t1_a   UNION ALL
40de9ed629Sdan    SELECT c, d FROM t1_b   UNION ALL
41de9ed629Sdan    SELECT e, f FROM t1_c
42de9ed629Sdan  ) ORDER BY a
43de9ed629Sdan} {
44de9ed629Sdan  1 one 2 two 3 three 4 four 5 five 6 six
45de9ed629Sdan}
46de9ed629Sdan
47de9ed629Sdando_execsql_test 1.2 {
48de9ed629Sdan  SELECT a, b FROM t1 ORDER BY a
49de9ed629Sdan} {
50de9ed629Sdan  1 one 2 two 3 three 4 four 5 five 6 six
51de9ed629Sdan}
52de9ed629Sdan
53de9ed629Sdando_execsql_test 1.3 {
54de9ed629Sdan  SELECT a, b FROM i1, t1 WHERE a=x ORDER BY a
55de9ed629Sdan} {1 one 2 two 5 five 6 six}
56de9ed629Sdan
57de9ed629Sdan
585fdb9a35Sdrh# 2022-10-31 part of ticket 57c47526c34f01e8
595fdb9a35Sdrh# The queries below were causing an assertion fault in
605fdb9a35Sdrh# the comparison operators of the VDBE.
615fdb9a35Sdrh#
625fdb9a35Sdrhreset_db
635fdb9a35Sdrhdatabase_never_corrupt
645fdb9a35Sdrhoptimization_control db all 0
655fdb9a35Sdrhdo_execsql_test 1.10 {
665fdb9a35Sdrh  CREATE TABLE t0(c0 INT);
675fdb9a35Sdrh  INSERT INTO t0 VALUES(0);
685fdb9a35Sdrh  CREATE TABLE t1_a(a INTEGER PRIMARY KEY, b TEXT);
695fdb9a35Sdrh  INSERT INTO t1_a VALUES(1,'one');
705fdb9a35Sdrh  CREATE TABLE t1_b(c INTEGER PRIMARY KEY, d TEXT);
715fdb9a35Sdrh  INSERT INTO t1_b VALUES(2,'two');
725fdb9a35Sdrh  CREATE VIEW t1 AS SELECT a, b FROM t1_a UNION ALL SELECT c, c FROM t1_b;
735fdb9a35Sdrh  SELECT * FROM (SELECT t1.a, t1.b AS b, t0.c0 FROM t0, t1);
745fdb9a35Sdrh} {1 one 0 2 2 0}
755fdb9a35Sdrhdo_execsql_test 1.11 {
765fdb9a35Sdrh  SELECT * FROM (SELECT t1.a, t1.b AS b, t0.c0 FROM t0, t1) WHERE b=2;
775fdb9a35Sdrh} {2 2 0}
785fdb9a35Sdrh
798daf5ae2Sdan#-------------------------------------------------------------------------
808daf5ae2Sdanreset_db
818daf5ae2Sdan
828daf5ae2Sdando_execsql_test 2.1.0 {
838daf5ae2Sdan  CREATE TABLE t1(x, y);
848daf5ae2Sdan  INSERT INTO t1 VALUES(1, 'one');
858daf5ae2Sdan  INSERT INTO t1 VALUES(1, 'ONE');
868daf5ae2Sdan  INSERT INTO t1 VALUES(2, 'two');
878daf5ae2Sdan  INSERT INTO t1 VALUES(2, 'TWO');
888daf5ae2Sdan  INSERT INTO t1 VALUES(3, 'three');
898daf5ae2Sdan  INSERT INTO t1 VALUES(3, 'THREE');
908daf5ae2Sdan}
918daf5ae2Sdan
928daf5ae2Sdando_execsql_test 2.1.1 {
938daf5ae2Sdan  WITH s(i) AS (
948daf5ae2Sdan      SELECT 1 UNION ALL SELECT i+1 FROM s WHERE i<3
958daf5ae2Sdan  )
968daf5ae2Sdan  SELECT * FROM (
978daf5ae2Sdan    SELECT 0 AS i UNION ALL SELECT i FROM s UNION ALL SELECT 0
988daf5ae2Sdan  ), t1 WHERE x=i;
998daf5ae2Sdan} {
1008daf5ae2Sdan  1 1 one 1 1 ONE 2 2 two 2 2 TWO 3 3 three 3 3 THREE
1018daf5ae2Sdan}
1028daf5ae2Sdan
1038daf5ae2Sdando_catchsql_test 2.1.2 {
1048daf5ae2Sdan  WITH s(i) AS (
1058daf5ae2Sdan      SELECT 1 UNION ALL SELECT i+1 FROM s WHERE i<3 UNION ALL SELECT 4
1068daf5ae2Sdan  )
1078daf5ae2Sdan  SELECT * FROM s, t1 WHERE x=i;
1088daf5ae2Sdan} {1 {circular reference: s}}
1098daf5ae2Sdan
1108daf5ae2Sdando_execsql_test 2.2.0 {
1118daf5ae2Sdan  CREATE TABLE t2_a(k INTEGER PRIMARY KEY, v TEXT);
1128daf5ae2Sdan  CREATE TABLE t2_b(k INTEGER PRIMARY KEY, v TEXT);
1138daf5ae2Sdan
1148daf5ae2Sdan  CREATE VIEW t2 AS
1158daf5ae2Sdan    SELECT * FROM t2_a
1168daf5ae2Sdan    UNION ALL
1178daf5ae2Sdan    SELECT * FROM t2_b;
1188daf5ae2Sdan
1198daf5ae2Sdan  CREATE TRIGGER t2_insert INSTEAD OF INSERT ON t2 BEGIN
1208daf5ae2Sdan    INSERT INTO t2_a SELECT new.k, new.v WHERE (new.k%2)==0;
1218daf5ae2Sdan    INSERT INTO t2_b SELECT new.k, new.v WHERE (new.k%2)==1;
1228daf5ae2Sdan  END;
1238daf5ae2Sdan
1248daf5ae2Sdan  INSERT INTO t2 VALUES(5, 'v'), (4, 'iv'), (3, 'iii'), (2, 'ii');
1258daf5ae2Sdan}
1268daf5ae2Sdan
1278daf5ae2Sdando_execsql_test 2.2.1 {
1288daf5ae2Sdan  SELECT * FROM t1, t2 WHERE x=k;
1298daf5ae2Sdan} {
1308daf5ae2Sdan  2 two 2 ii 2 TWO 2 ii 3 three 3 iii 3 THREE 3 iii
1318daf5ae2Sdan}
1328daf5ae2Sdan
1338daf5ae2Sdando_execsql_test 2.2.2 {
1348daf5ae2Sdan  SELECT * FROM t1 LEFT JOIN t2 ON (x=k);
1358daf5ae2Sdan} {
1368daf5ae2Sdan  1 one {} {}
1378daf5ae2Sdan  1 ONE {} {}
1388daf5ae2Sdan  2 two 2 ii 2 TWO 2 ii 3 three 3 iii 3 THREE 3 iii
1398daf5ae2Sdan}
1408daf5ae2Sdan
1418daf5ae2Sdando_execsql_test 2.2.3 {
1428daf5ae2Sdan  SELECT x1.*, x2.* FROM t2 AS x1, t2 AS x2 WHERE x1.k=x2.k+1
1438daf5ae2Sdan} {
1448daf5ae2Sdan  4 iv   3 iii
1458daf5ae2Sdan  3 iii  2 ii
1468daf5ae2Sdan  5 v    4 iv
1478daf5ae2Sdan}
1488daf5ae2Sdan
1498daf5ae2Sdando_execsql_test 2.2.4 {
1508daf5ae2Sdan  SELECT * FROM t1, t2 WHERE x=k ORDER BY y;
1518daf5ae2Sdan} {
1528daf5ae2Sdan  3 THREE 3 iii
1538daf5ae2Sdan  2 TWO 2 ii
1548daf5ae2Sdan  3 three 3 iii
1558daf5ae2Sdan  2 two 2 ii
1568daf5ae2Sdan}
1578daf5ae2Sdando_execsql_test 2.2.5 {
1588daf5ae2Sdan  SELECT * FROM t1, t2 WHERE x=k ORDER BY y||'';
1598daf5ae2Sdan} {
1608daf5ae2Sdan  3 THREE 3 iii
1618daf5ae2Sdan  2 TWO 2 ii
1628daf5ae2Sdan  3 three 3 iii
1638daf5ae2Sdan  2 two 2 ii
1648daf5ae2Sdan}
1658daf5ae2Sdando_execsql_test 2.2.6 {
1668daf5ae2Sdan  SELECT * FROM t1, t2 WHERE x=k ORDER BY v
1678daf5ae2Sdan} {
1688daf5ae2Sdan  2 two   2 ii
1698daf5ae2Sdan  2 TWO   2 ii
1708daf5ae2Sdan  3 three 3 iii
1718daf5ae2Sdan  3 THREE 3 iii
1728daf5ae2Sdan}
1738daf5ae2Sdando_execsql_test 2.2.7 {
1748daf5ae2Sdan  SELECT * FROM t1, t2 WHERE x=k ORDER BY v||''
1758daf5ae2Sdan} {
1768daf5ae2Sdan  2 two   2 ii
1778daf5ae2Sdan  2 TWO   2 ii
1788daf5ae2Sdan  3 three 3 iii
1798daf5ae2Sdan  3 THREE 3 iii
1808daf5ae2Sdan}
1818daf5ae2Sdando_execsql_test 2.2.8 {
1828daf5ae2Sdan  SELECT * FROM t1, t2 WHERE x=k ORDER BY k,v||''
1838daf5ae2Sdan} {
1848daf5ae2Sdan  2 two   2 ii
1858daf5ae2Sdan  2 TWO   2 ii
1868daf5ae2Sdan  3 three 3 iii
1878daf5ae2Sdan  3 THREE 3 iii
1888daf5ae2Sdan}
189964fa26eSdando_execsql_test 2.2.9a {
190964fa26eSdan  SELECT * FROM t1, t2 ORDER BY +k
191964fa26eSdan} {
192964fa26eSdan  1 one 2 ii 1 ONE 2 ii 2 two 2 ii
193964fa26eSdan  2 TWO 2 ii 3 three 2 ii 3 THREE 2 ii
194964fa26eSdan
195964fa26eSdan  1 one 3 iii 1 ONE 3 iii 2 two 3 iii
196964fa26eSdan  2 TWO 3 iii 3 three 3 iii 3 THREE 3 iii
197964fa26eSdan
198964fa26eSdan  1 one 4 iv 1 ONE 4 iv 2 two 4 iv
199964fa26eSdan  2 TWO 4 iv 3 three 4 iv 3 THREE 4 iv
200964fa26eSdan
201964fa26eSdan  1 one 5 v 1 ONE 5 v 2 two 5 v
202964fa26eSdan  2 TWO 5 v 3 three 5 v 3 THREE 5 v
203964fa26eSdan}
204964fa26eSdan
205964fa26eSdando_execsql_test 2.2.9b {
206964fa26eSdan  SELECT * FROM t1, t2 ORDER BY k
207964fa26eSdan} {
208964fa26eSdan  1 one 2 ii 1 ONE 2 ii 2 two 2 ii
209964fa26eSdan  2 TWO 2 ii 3 three 2 ii 3 THREE 2 ii
210964fa26eSdan
211964fa26eSdan  1 one 3 iii 1 ONE 3 iii 2 two 3 iii
212964fa26eSdan  2 TWO 3 iii 3 three 3 iii 3 THREE 3 iii
213964fa26eSdan
214964fa26eSdan  1 one 4 iv 1 ONE 4 iv 2 two 4 iv
215964fa26eSdan  2 TWO 4 iv 3 three 4 iv 3 THREE 4 iv
216964fa26eSdan
217964fa26eSdan  1 one 5 v 1 ONE 5 v 2 two 5 v
218964fa26eSdan  2 TWO 5 v 3 three 5 v 3 THREE 5 v
219964fa26eSdan}
2208daf5ae2Sdan
221d131b51cSdan#-------------------------------------------------------------------------
222d131b51cSdanreset_db
223d131b51cSdando_execsql_test 3.0 {
224d131b51cSdan  CREATE TABLE t1(c INTEGER PRIMARY KEY, d TEXT);
225d131b51cSdan  INSERT INTO t1 VALUES(1,2);
226d131b51cSdan  CREATE TABLE t3_a(k INTEGER PRIMARY KEY, v TEXT);
227d131b51cSdan  INSERT INTO t3_a VALUES(2,'ii');
228d131b51cSdan  CREATE TABLE t3_b(k INTEGER PRIMARY KEY, v TEXT);
229d131b51cSdan  CREATE VIEW t3 AS
230d131b51cSdan    SELECT * FROM t3_a
231d131b51cSdan    UNION ALL
232d131b51cSdan    SELECT * FROM t3_b;
233d131b51cSdan} {}
234d131b51cSdan
235d131b51cSdando_execsql_test 3.1 {
236d131b51cSdan  SELECT * FROM t1, t3 ORDER BY k;
237d131b51cSdan} {1 2 2 ii}
238d131b51cSdan
239d131b51cSdanreset_db
240d131b51cSdando_execsql_test 4.0 {
241d131b51cSdan
242d131b51cSdan  CREATE TABLE t1_a(a INTEGER PRIMARY KEY, b TEXT);
243d131b51cSdan  INSERT INTO t1_a VALUES(123, 't1_a');
244d131b51cSdan  CREATE TABLE t1_b(c INTEGER PRIMARY KEY, d TEXT);
245d131b51cSdan
246d131b51cSdan  CREATE VIEW t1 AS
247d131b51cSdan    SELECT a, b FROM t1_a
248d131b51cSdan    UNION ALL
249d131b51cSdan    SELECT c, d FROM t1_b;
250d131b51cSdan
251d131b51cSdan  CREATE TABLE t3_a(k INTEGER PRIMARY KEY, v TEXT);
252d131b51cSdan  INSERT INTO t3_a VALUES(456, 't3_a');
253d131b51cSdan  CREATE TABLE t3_b(k INTEGER PRIMARY KEY, v TEXT);
254d131b51cSdan
255d131b51cSdan  CREATE VIEW t3 AS
256d131b51cSdan    SELECT * FROM t3_a
257d131b51cSdan    UNION ALL
258d131b51cSdan    SELECT * FROM t3_b;
259d131b51cSdan}
260d131b51cSdan
261d131b51cSdando_execsql_test 4.1 {
262d131b51cSdan  SELECT * FROM t1, t3 ORDER BY k;
263d131b51cSdan} {123 t1_a 456 t3_a}
264d131b51cSdan
265d131b51cSdando_execsql_test 4.2 {
266d131b51cSdan  SELECT * FROM (SELECT * FROM t1, t3) ORDER BY k;
267d131b51cSdan} {123 t1_a 456 t3_a}
2688daf5ae2Sdan
269a3d33ebeSdando_execsql_test 4.3 {
270a3d33ebeSdan  SELECT * FROM (SELECT * FROM t1, t3), (
271a3d33ebeSdan    SELECT max(a) OVER () FROM t1
272a3d33ebeSdan      UNION ALL
273a3d33ebeSdan    SELECT min(a) OVER () FROM t1
274a3d33ebeSdan  )
275a3d33ebeSdan  ORDER BY k;
276a3d33ebeSdan} {
277a3d33ebeSdan  123 t1_a 456 t3_a 123
278a3d33ebeSdan  123 t1_a 456 t3_a 123
279a3d33ebeSdan}
280a3d33ebeSdan
281a3d33ebeSdando_execsql_test 4.3 {
282a3d33ebeSdan  SELECT * FROM (SELECT * FROM t1, t3), (
283a3d33ebeSdan    SELECT group_concat(a) OVER (ORDER BY a),
284a3d33ebeSdan           group_concat(a) OVER (ORDER BY a),
285a3d33ebeSdan           group_concat(a) OVER (ORDER BY a),
286a3d33ebeSdan           group_concat(a) OVER (ORDER BY a),
287a3d33ebeSdan           group_concat(a) OVER (ORDER BY a),
288a3d33ebeSdan           group_concat(a) OVER (ORDER BY a),
289a3d33ebeSdan           group_concat(a) OVER (ORDER BY a),
290a3d33ebeSdan           group_concat(a) OVER (ORDER BY a),
291a3d33ebeSdan           group_concat(a) OVER (ORDER BY a)
292a3d33ebeSdan    FROM t1
293a3d33ebeSdan  )
294a3d33ebeSdan  ORDER BY k;
295a3d33ebeSdan} {
296a3d33ebeSdan  123 t1_a 456 t3_a 123 123 123 123 123 123 123 123 123
297a3d33ebeSdan}
298a3d33ebeSdan
299961a7260Sdando_execsql_test 4.3 {
300961a7260Sdan  SELECT * FROM (SELECT * FROM t1, t3) AS o, (
301961a7260Sdan    SELECT * FROM t1 LEFT JOIN t3 ON a=k
302961a7260Sdan  );
303961a7260Sdan} {
304961a7260Sdan  123 t1_a 456 t3_a 123 t1_a {} {}
305961a7260Sdan}
306961a7260Sdan
307c4403ca6Sdrh# 2020-12-30: dbsqlfuzz find
308c4403ca6Sdrhreset_db
309c4403ca6Sdrhdo_execsql_test 5.1 {
310c4403ca6Sdrh  CREATE TABLE t1_a(a INTEGER PRIMARY KEY, b TEXT);
311c4403ca6Sdrh  INSERT INTO t1_a VALUES(1,'one');
312c4403ca6Sdrh  INSERT INTO t1_a VALUES(0,NULL);
313c4403ca6Sdrh  CREATE TABLE t1_b(c INTEGER PRIMARY KEY, d TEXT);
314c4403ca6Sdrh  INSERT INTO t1_b VALUES(2,'two');
315c4403ca6Sdrh  INSERT INTO t1_b VALUES(5,'five');
316c4403ca6Sdrh  CREATE TABLE t1_c(e INTEGER PRIMARY KEY, f TEXT);
317c4403ca6Sdrh  INSERT INTO t1_c VALUES(3,'three');
318c4403ca6Sdrh  INSERT INTO t1_c VALUES(6,'six');
319c4403ca6Sdrh  CREATE TABLE t2(k,v);
320c4403ca6Sdrh  INSERT INTO t2 VALUES(5,'v');
321c4403ca6Sdrh  INSERT INTO t2 VALUES(4,'iv');
322c4403ca6Sdrh  INSERT INTO t2 VALUES(3,'iii');
323c4403ca6Sdrh  INSERT INTO t2 VALUES(2,'ii');
324c4403ca6Sdrh  CREATE TABLE t3_a(k INTEGER PRIMARY KEY, v TEXT);
325c4403ca6Sdrh  INSERT INTO t3_a VALUES(2,'ii');
326c4403ca6Sdrh  INSERT INTO t3_a VALUES(4,'iv');
327c4403ca6Sdrh  CREATE TABLE t3_b(k INTEG5R PRIMARY KEY, v TEXT);
328c4403ca6Sdrh  INSERT INTO t3_b VALUES(NULL,'iii');
329c4403ca6Sdrh  INSERT INTO t3_b VALUES(NULL,'v');
330c4403ca6Sdrh  CREATE VIEW t1 AS
331c4403ca6Sdrh    SELECT a, b FROM t1_a   UNION ALL
332c4403ca6Sdrh    SELECT c, d FROM t1_b   UNION ALL
333c4403ca6Sdrh    SELECT e, f FROM t1_c;
334c4403ca6Sdrh  CREATE VIEW t3 AS
335c4403ca6Sdrh      SELECT * FROM t3_a
336c4403ca6Sdrh      UNION ALL
337c4403ca6Sdrh      SELECT * FROM t3_b;
338c4403ca6Sdrh  CREATE TRIGGER t3_insert INSTEAD OF INSERT ON t3 BEGIN
339c4403ca6Sdrh      INSERT INTO t3_a SELECT new.k, new.v WHERE (new.k%2)==0;
340c4403ca6Sdrh      INSERT INTO t3_b SELECT new.k, new.v WHERE (new.k%2)==1;
341c4403ca6Sdrh  END;
342c4403ca6Sdrh} {}
343c4403ca6Sdrhdo_execsql_test 5.10 {
344c4403ca6Sdrh  SELECT *, '+' FROM t1 LEFT JOIN t2 ON (a NOT IN(SELECT v FROM t1, t3 WHERE a=k)=NOT EXISTS(SELECT 1 FROM t1 LEFT JOIN t3 ON (a=k)));
345c4403ca6Sdrh} {0 {} {} {} + 1 one {} {} + 2 two {} {} + 5 five {} {} + 3 three {} {} + 6 six {} {} +}
346c4403ca6Sdrhdo_execsql_test 5.20 {
347c4403ca6Sdrh  SELECT *, '+' FROM t1 LEFT JOIN t3 ON (a NOT IN(SELECT v FROM t1 LEFT JOIN t2 ON (a=k))=k);
348c4403ca6Sdrh} {0 {} {} {} + 1 one {} {} + 2 two {} {} + 5 five {} {} + 3 three {} {} + 6 six {} {} +}
349c4403ca6Sdrh
350e8f1490fSdanreset_db
351e8f1490fSdando_execsql_test 6.0 {
352e8f1490fSdan  CREATE TABLE t1(a,b);
353e8f1490fSdan  INSERT INTO t1 VALUES(1,2);
354e8f1490fSdan  CREATE TABLE t2(a,b);
355e8f1490fSdan  INSERT INTO t2 VALUES(3,4);
356e8f1490fSdan
357e8f1490fSdan  CREATE TABLE t3(a,b);
358e8f1490fSdan  INSERT INTO t3 VALUES(5,6);
359e8f1490fSdan  CREATE TABLE t4(a,b);
360e8f1490fSdan  INSERT INTO t4 VALUES(7,8);
361e8f1490fSdan
362e8f1490fSdan  CREATE TABLE t5(a,b);
363e8f1490fSdan  INSERT INTO t5 VALUES(9,10);
364e8f1490fSdan}
365e8f1490fSdan
366e8f1490fSdando_execsql_test 6.1 {
367e8f1490fSdan  WITH x(c) AS (
368e8f1490fSdan    SELECT 1000 FROM t1 UNION ALL SELECT 800 FROM t2
369e8f1490fSdan  ),
370e8f1490fSdan  y(d) AS (
371e8f1490fSdan    SELECT  100 FROM t3 UNION ALL SELECT 400 FROM t4
372e8f1490fSdan  )
373e8f1490fSdan  SELECT * FROM t5, x, y;
374e8f1490fSdan} {
375e8f1490fSdan  9 10 1000 100     9 10 1000 400
376e8f1490fSdan  9 10 800 100      9 10 800 400
377e8f1490fSdan}
378e8f1490fSdan
379c7f5077eSdrh# 2021-04-26 dbsqlfuzz 88ed5c66789fced139d148aed823cba7c0926dd7
380c7f5077eSdrhreset_db
381c7f5077eSdrhdo_execsql_test 7.1 {
382c7f5077eSdrh  WITH c1(x) AS (VALUES(0) UNION ALL SELECT 100+x FROM c1 WHERE x<100 UNION ALL SELECT 1+x FROM c1 WHERE x<1)
383c7f5077eSdrh  SELECT x, y, '|'
384c7f5077eSdrh    FROM c1 AS x1, (SELECT x+1 AS y FROM c1 WHERE x<1 UNION ALL SELECT 1+x FROM c1 WHERE 1<x) AS x2
385c7f5077eSdrh   ORDER BY x, y;
386c7f5077eSdrh} {0 1 | 0 101 | 0 102 | 1 1 | 1 101 | 1 102 | 100 1 | 100 101 | 100 102 | 101 1 | 101 101 | 101 102 |}
387c7f5077eSdrh
388*b6d91679Sdrh# 2022-10-31 ticket https://sqlite.org/src/info/57c47526c34f01e8
389*b6d91679Sdrh# dbsqlfuzz 37230460b46b3b6049f0d768eb801f3428189382
390*b6d91679Sdrh# UNION ALL subqueries or views which have arms with different
391*b6d91679Sdrh# affinities should not be flattened.
392*b6d91679Sdrh#
393*b6d91679Sdrhreset_db
394*b6d91679Sdrhdo_execsql_test 8.1 {
395*b6d91679Sdrh  CREATE TABLE t0(c0 INT);
396*b6d91679Sdrh  INSERT INTO t0 VALUES(0);
397*b6d91679Sdrh  CREATE TABLE t1_a(a INTEGER PRIMARY KEY, b TEXT);
398*b6d91679Sdrh  INSERT INTO t1_a VALUES(1,'one');
399*b6d91679Sdrh  INSERT INTO t1_a VALUES(4,'four');
400*b6d91679Sdrh  CREATE TABLE t1_b(c INTEGER PRIMARY KEY, d TEXT);
401*b6d91679Sdrh  INSERT INTO t1_b VALUES(2,'two');
402*b6d91679Sdrh  INSERT INTO t1_b VALUES(5,'five');
403*b6d91679Sdrh  CREATE TABLE t1_c(e INTEGER PRIMARY KEY, f TEXT);
404*b6d91679Sdrh  INSERT INTO t1_c VALUES(3,'three');
405*b6d91679Sdrh  INSERT INTO t1_c VALUES(6,'six');
406*b6d91679Sdrh  CREATE VIEW v0(c0) AS SELECT CAST(t0.c0 AS INTEGER) FROM t0;
407*b6d91679Sdrh  CREATE VIEW t1 AS
408*b6d91679Sdrh    SELECT a, b FROM t1_a   UNION ALL
409*b6d91679Sdrh    SELECT c, c FROM t1_b   UNION ALL
410*b6d91679Sdrh    SELECT e, f FROM t1_c;
411*b6d91679Sdrh}
412*b6d91679Sdrhoptimization_control db all 1
413*b6d91679Sdrhdo_execsql_test 8.2 {
414*b6d91679Sdrh  SELECT * FROM (SELECT t1.a, t1.b, t0.c0 AS c, v0.c0 AS d FROM t0 LEFT JOIN v0 ON v0.c0>'0',t1) WHERE b=2;
415*b6d91679Sdrh} {2 2 0 {}}
416*b6d91679Sdrhdo_execsql_test 8.3 {
417*b6d91679Sdrh  SELECT * FROM (SELECT t1.a, t1.b, t0.c0 AS c, v0.c0 AS d FROM t0 LEFT JOIN v0 ON v0.c0>'0',t1) WHERE b=2.0;
418*b6d91679Sdrh} {}
419*b6d91679Sdrhdo_execsql_test 8.4 {
420*b6d91679Sdrh  SELECT * FROM (SELECT t1.a, t1.b, t0.c0 AS c, v0.c0 AS d FROM t0 LEFT JOIN v0 ON v0.c0>'0',t1) WHERE b='2';
421*b6d91679Sdrh} {2 2 0 {}}
422*b6d91679Sdrhoptimization_control db query-flattener,push-down 0
423*b6d91679Sdrhdo_execsql_test 8.5 {
424*b6d91679Sdrh  SELECT * FROM (SELECT t1.a, t1.b, t0.c0 AS c, v0.c0 AS d FROM t0 LEFT JOIN v0 ON v0.c0>'0',t1) WHERE b=2;
425*b6d91679Sdrh} {2 2 0 {}}
426*b6d91679Sdrhdo_execsql_test 8.6 {
427*b6d91679Sdrh  SELECT * FROM (SELECT t1.a, t1.b, t0.c0 AS c, v0.c0 AS d FROM t0 LEFT JOIN v0 ON v0.c0>'0',t1) WHERE b=2.0;
428*b6d91679Sdrh} {}
429*b6d91679Sdrhdo_execsql_test 8.7 {
430*b6d91679Sdrh  SELECT * FROM (SELECT t1.a, t1.b, t0.c0 AS c, v0.c0 AS d FROM t0 LEFT JOIN v0 ON v0.c0>'0',t1) WHERE b='2';
431*b6d91679Sdrh} {2 2 0 {}}
432*b6d91679Sdrhoptimization_control db all 0
433*b6d91679Sdrhdo_execsql_test 8.8 {
434*b6d91679Sdrh  SELECT * FROM (SELECT t1.a, t1.b, t0.c0 AS c, v0.c0 AS d FROM t0 LEFT JOIN v0 ON v0.c0>'0',t1) WHERE b=2;
435*b6d91679Sdrh} {2 2 0 {}}
436*b6d91679Sdrhdo_execsql_test 8.9 {
437*b6d91679Sdrh  SELECT * FROM (SELECT t1.a, t1.b, t0.c0 AS c, v0.c0 AS d FROM t0 LEFT JOIN v0 ON v0.c0>'0',t1) WHERE b=2.0;
438*b6d91679Sdrh} {}
439*b6d91679Sdrhdo_execsql_test 8.10 {
440*b6d91679Sdrh  SELECT * FROM (SELECT t1.a, t1.b, t0.c0 AS c, v0.c0 AS d FROM t0 LEFT JOIN v0 ON v0.c0>'0',t1) WHERE b='2';
441*b6d91679Sdrh} {2 2 0 {}}
442*b6d91679Sdrh
443*b6d91679Sdrh
444de9ed629Sdanfinish_test
445