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 testing UNION, INTERSECT and EXCEPT operators
13 # in SELECT statements.
16 set testdir [file dirname $argv0]
17 source $testdir/tester.tcl
19 # Most tests in this file depend on compound-select. But there are a couple
20 # right at the end that test DISTINCT, so we cannot omit the entire file.
24 # Build some test data
27 CREATE TABLE t1(n int, log int);
30 for {set i 1} {$i<32} {incr i} {
31 for {set j 0} {(1<<$j)<$i} {incr j} {}
32 execsql "INSERT INTO t1 VALUES($i,$j)"
39 execsql {SELECT DISTINCT log FROM t1 ORDER BY log}
44 do_test select4-1.1a {
45 lsort [execsql {SELECT DISTINCT log FROM t1}]
47 do_test select4-1.1b {
48 lsort [execsql {SELECT n FROM t1 WHERE log=3}]
50 do_test select4-1.1c {
52 SELECT DISTINCT log FROM t1
54 SELECT n FROM t1 WHERE log=3
57 } {0 1 2 3 4 5 5 6 7 8}
58 do_test select4-1.1d {
61 SELECT DISTINCT log FROM t1
63 SELECT n FROM t1 WHERE log=3
67 } {0 1 2 3 4 5 5 6 7 8}
68 execsql {DROP TABLE t2}
69 do_test select4-1.1e {
72 SELECT DISTINCT log FROM t1
74 SELECT n FROM t1 WHERE log=3
78 } {8 7 6 5 5 4 3 2 1 0}
79 execsql {DROP TABLE t2}
80 do_test select4-1.1f {
82 SELECT DISTINCT log FROM t1
84 SELECT n FROM t1 WHERE log=2
87 do_test select4-1.1g {
90 SELECT DISTINCT log FROM t1
92 SELECT n FROM t1 WHERE log=2;
96 execsql {DROP TABLE t2}
100 SELECT log FROM t1 WHERE n IN
101 (SELECT DISTINCT log FROM t1 UNION ALL
102 SELECT n FROM t1 WHERE log=3)
108 # EVIDENCE-OF: R-02644-22131 In a compound SELECT statement, only the
109 # last or right-most simple SELECT may have an ORDER BY clause.
111 do_test select4-1.3 {
112 set v [catch {execsql {
113 SELECT DISTINCT log FROM t1 ORDER BY log
115 SELECT n FROM t1 WHERE log=3
119 } {1 {ORDER BY clause should come after UNION ALL not before}}
120 do_catchsql_test select4-1.4 {
121 SELECT (VALUES(0) INTERSECT SELECT(0) UNION SELECT(0) ORDER BY 1 UNION
122 SELECT 0 UNION SELECT 0 ORDER BY 1);
123 } {1 {ORDER BY clause should come after UNION not before}}
127 do_test select4-2.1 {
129 SELECT DISTINCT log FROM t1
131 SELECT n FROM t1 WHERE log=3
134 } {0 1 2 3 4 5 6 7 8}
136 do_test select4-2.2 {
138 SELECT log FROM t1 WHERE n IN
139 (SELECT DISTINCT log FROM t1 UNION
140 SELECT n FROM t1 WHERE log=3)
145 do_test select4-2.3 {
146 set v [catch {execsql {
147 SELECT DISTINCT log FROM t1 ORDER BY log
149 SELECT n FROM t1 WHERE log=3
153 } {1 {ORDER BY clause should come after UNION not before}}
154 do_test select4-2.4 {
155 set v [catch {execsql {
156 SELECT 0 ORDER BY (SELECT 0) UNION SELECT 0;
159 } {1 {ORDER BY clause should come after UNION not before}}
160 do_execsql_test select4-2.5 {
161 SELECT 123 AS x ORDER BY (SELECT x ORDER BY 1);
166 do_test select4-3.1.1 {
168 SELECT DISTINCT log FROM t1
170 SELECT n FROM t1 WHERE log=3
174 do_test select4-3.1.2 {
177 SELECT DISTINCT log FROM t1
179 SELECT n FROM t1 WHERE log=3
184 execsql {DROP TABLE t2}
185 do_test select4-3.1.3 {
188 SELECT DISTINCT log FROM t1
190 SELECT n FROM t1 WHERE log=3
195 execsql {DROP TABLE t2}
197 do_test select4-3.2 {
199 SELECT log FROM t1 WHERE n IN
200 (SELECT DISTINCT log FROM t1 EXCEPT
201 SELECT n FROM t1 WHERE log=3)
206 do_test select4-3.3 {
207 set v [catch {execsql {
208 SELECT DISTINCT log FROM t1 ORDER BY log
210 SELECT n FROM t1 WHERE log=3
214 } {1 {ORDER BY clause should come after EXCEPT not before}}
218 do_test select4-4.1.1 {
220 SELECT DISTINCT log FROM t1
222 SELECT n FROM t1 WHERE log=3
227 do_test select4-4.1.2 {
229 SELECT DISTINCT log FROM t1
233 SELECT n FROM t1 WHERE log=3
238 do_test select4-4.1.3 {
241 SELECT DISTINCT log FROM t1 UNION ALL SELECT 6
243 SELECT n FROM t1 WHERE log=3
248 execsql {DROP TABLE t2}
249 do_test select4-4.1.4 {
252 SELECT DISTINCT log FROM t1 UNION ALL SELECT 6
254 SELECT n FROM t1 WHERE log=3
259 execsql {DROP TABLE t2}
261 do_test select4-4.2 {
263 SELECT log FROM t1 WHERE n IN
264 (SELECT DISTINCT log FROM t1 INTERSECT
265 SELECT n FROM t1 WHERE log=3)
270 do_test select4-4.3 {
271 set v [catch {execsql {
272 SELECT DISTINCT log FROM t1 ORDER BY log
274 SELECT n FROM t1 WHERE log=3
278 } {1 {ORDER BY clause should come after INTERSECT not before}}
279 do_catchsql_test select4-4.4 {
288 } {1 {ORDER BY clause should come after INTERSECT not before}}
290 # Various error messages while processing UNION or INTERSECT
292 do_test select4-5.1 {
293 set v [catch {execsql {
294 SELECT DISTINCT log FROM t2
296 SELECT n FROM t1 WHERE log=3
300 } {1 {no such table: t2}}
301 do_test select4-5.2 {
302 set v [catch {execsql {
303 SELECT DISTINCT log AS "xyzzy" FROM t1
305 SELECT n FROM t1 WHERE log=3
309 } {0 {0 1 2 3 4 5 5 6 7 8}}
310 do_test select4-5.2b {
311 set v [catch {execsql {
312 SELECT DISTINCT log AS xyzzy FROM t1
314 SELECT n FROM t1 WHERE log=3
318 } {0 {0 1 2 3 4 5 5 6 7 8}}
319 do_test select4-5.2c {
320 set v [catch {execsql {
321 SELECT DISTINCT log FROM t1
323 SELECT n FROM t1 WHERE log=3
327 } {1 {1st ORDER BY term does not match any column in the result set}}
328 do_test select4-5.2d {
329 set v [catch {execsql {
330 SELECT DISTINCT log FROM t1
332 SELECT n FROM t1 WHERE log=3
336 } {1 {1st ORDER BY term does not match any column in the result set}}
337 do_test select4-5.2e {
338 set v [catch {execsql {
339 SELECT DISTINCT log FROM t1
341 SELECT n FROM t1 WHERE log=3
345 } {0 {0 1 2 3 4 5 5 6 7 8}}
346 do_test select4-5.2f {
348 SELECT DISTINCT log FROM t1
350 SELECT n FROM t1 WHERE log=3
353 } {0 {0 1 2 3 4 5 5 6 7 8}}
354 do_test select4-5.2g {
356 SELECT DISTINCT log FROM t1
358 SELECT n FROM t1 WHERE log=3
361 } {0 {0 1 2 3 4 5 5 6 7 8}}
362 do_test select4-5.2h {
364 SELECT DISTINCT log FROM t1
366 SELECT n FROM t1 WHERE log=3
369 } {1 {1st ORDER BY term out of range - should be between 1 and 1}}
370 do_test select4-5.2i {
372 SELECT DISTINCT 1, log FROM t1
374 SELECT 2, n FROM t1 WHERE log=3
377 } {0 {1 0 1 1 1 2 1 3 1 4 1 5 2 5 2 6 2 7 2 8}}
378 do_test select4-5.2j {
380 SELECT DISTINCT 1, log FROM t1
382 SELECT 2, n FROM t1 WHERE log=3
385 } {0 {1 5 1 4 1 3 1 2 1 1 1 0 2 8 2 7 2 6 2 5}}
386 do_test select4-5.2k {
388 SELECT DISTINCT 1, log FROM t1
390 SELECT 2, n FROM t1 WHERE log=3
393 } {0 {1 0 1 1 1 2 1 3 1 4 1 5 2 5 2 6 2 7 2 8}}
394 do_test select4-5.3 {
395 set v [catch {execsql {
396 SELECT DISTINCT log, n FROM t1
398 SELECT n FROM t1 WHERE log=3
402 } {1 {SELECTs to the left and right of UNION ALL do not have the same number of result columns}}
403 do_test select4-5.3-3807-1 {
405 SELECT 1 UNION SELECT 2, 3 UNION SELECT 4, 5 ORDER BY 1;
407 } {1 {SELECTs to the left and right of UNION do not have the same number of result columns}}
408 do_test select4-5.4 {
409 set v [catch {execsql {
410 SELECT log FROM t1 WHERE n=2
412 SELECT log FROM t1 WHERE n=3
414 SELECT log FROM t1 WHERE n=4
416 SELECT log FROM t1 WHERE n=5
422 do_test select4-6.1 {
424 SELECT log, count(*) as cnt FROM t1 GROUP BY log
426 SELECT log, n FROM t1 WHERE n=7
429 } {0 1 1 1 2 2 3 4 3 7 4 8 5 15}
430 do_test select4-6.2 {
432 SELECT log, count(*) FROM t1 GROUP BY log
434 SELECT log, n FROM t1 WHERE n=7
435 ORDER BY count(*), log;
437 } {0 1 1 1 2 2 3 4 3 7 4 8 5 15}
439 # NULLs are indistinct for the UNION operator.
440 # Make sure the UNION operator recognizes this
442 do_test select4-6.3 {
444 SELECT NULL UNION SELECT NULL UNION
445 SELECT 1 UNION SELECT 2 AS 'x'
449 do_test select4-6.3.1 {
451 SELECT NULL UNION ALL SELECT NULL UNION ALL
452 SELECT 1 UNION ALL SELECT 2 AS 'x'
457 # Make sure the DISTINCT keyword treats NULLs as indistinct.
460 do_test select4-6.4 {
463 SELECT NULL, 1 UNION ALL SELECT NULL, 1
467 do_test select4-6.5 {
469 SELECT DISTINCT * FROM (
470 SELECT NULL, 1 UNION ALL SELECT NULL, 1
474 do_test select4-6.6 {
476 SELECT DISTINCT * FROM (
477 SELECT 1,2 UNION ALL SELECT 1,2
483 # Test distinctness of NULL in other ways.
485 do_test select4-6.7 {
487 SELECT NULL EXCEPT SELECT NULL
492 # Make sure column names are correct when a compound select appears as
493 # an expression in the WHERE clause.
495 do_test select4-7.1 {
497 CREATE TABLE t2 AS SELECT log AS 'x', count(*) AS 'y' FROM t1 GROUP BY log;
498 SELECT * FROM t2 ORDER BY x;
500 } {0 1 1 1 2 2 3 4 4 8 5 15}
502 do_test select4-7.2 {
504 SELECT * FROM t1 WHERE n IN (SELECT n FROM t1 INTERSECT SELECT x FROM t2)
507 } {n 1 log 0 n 2 log 1 n 3 log 2 n 4 log 2 n 5 log 3}
508 do_test select4-7.3 {
510 SELECT * FROM t1 WHERE n IN (SELECT n FROM t1 EXCEPT SELECT x FROM t2)
513 } {n 6 log 3 n 7 log 3}
514 do_test select4-7.4 {
516 SELECT * FROM t1 WHERE n IN (SELECT n FROM t1 UNION SELECT x FROM t2)
519 } {n 1 log 0 n 2 log 1}
520 } ;# ifcapable subquery
522 } ;# ifcapable compound
524 # Make sure DISTINCT works appropriately on TEXT and NUMERIC columns.
525 do_test select4-8.1 {
528 CREATE TABLE t3(a text, b float, c text);
529 INSERT INTO t3 VALUES(1, 1.1, '1.1');
530 INSERT INTO t3 VALUES(2, 1.10, '1.10');
531 INSERT INTO t3 VALUES(3, 1.10, '1.1');
532 INSERT INTO t3 VALUES(4, 1.1, '1.10');
533 INSERT INTO t3 VALUES(5, 1.2, '1.2');
534 INSERT INTO t3 VALUES(6, 1.3, '1.3');
538 SELECT DISTINCT b FROM t3 ORDER BY c;
541 do_test select4-8.2 {
543 SELECT DISTINCT c FROM t3 ORDER BY c;
547 # Make sure the names of columns are taken from the right-most subquery
548 # right in a compound query. Ticket #1721
552 do_test select4-9.1 {
554 SELECT x, y FROM t2 UNION SELECT a, b FROM t3 ORDER BY x LIMIT 1
557 do_test select4-9.2 {
559 SELECT x, y FROM t2 UNION ALL SELECT a, b FROM t3 ORDER BY x LIMIT 1
562 do_test select4-9.3 {
564 SELECT x, y FROM t2 EXCEPT SELECT a, b FROM t3 ORDER BY x LIMIT 1
567 do_test select4-9.4 {
569 SELECT x, y FROM t2 INTERSECT SELECT 0 AS a, 1 AS b;
572 do_test select4-9.5 {
574 SELECT 0 AS x, 1 AS y
576 SELECT 2 AS p, 3 AS q
578 SELECT 4 AS a, 5 AS b
584 do_test select4-9.6 {
587 SELECT 0 AS x, 1 AS y
589 SELECT 2 AS p, 3 AS q
591 SELECT 4 AS a, 5 AS b
592 ) ORDER BY 1 LIMIT 1;
595 do_test select4-9.7 {
598 SELECT 0 AS x, 1 AS y
600 SELECT 2 AS p, 3 AS q
602 SELECT 4 AS a, 5 AS b
603 ) ORDER BY x LIMIT 1;
606 } ;# ifcapable subquery
608 do_test select4-9.8 {
610 SELECT 0 AS x, 1 AS y
612 SELECT 2 AS y, -3 AS x
617 do_test select4-9.9.1 {
619 SELECT 1 AS a, 2 AS b UNION ALL SELECT 3 AS b, 4 AS a
624 do_test select4-9.9.2 {
626 SELECT * FROM (SELECT 1 AS a, 2 AS b UNION ALL SELECT 3 AS b, 4 AS a)
630 do_test select4-9.10 {
632 SELECT * FROM (SELECT 1 AS a, 2 AS b UNION ALL SELECT 3 AS b, 4 AS a)
636 do_test select4-9.11 {
638 SELECT * FROM (SELECT 1 AS a, 2 AS b UNION ALL SELECT 3 AS e, 4 AS b)
642 do_test select4-9.12 {
644 SELECT * FROM (SELECT 1 AS a, 2 AS b UNION ALL SELECT 3 AS e, 4 AS b)
648 } ;# ifcapable subquery
650 # Try combining DISTINCT, LIMIT, and OFFSET. Make sure they all work
653 do_test select4-10.1 {
655 SELECT DISTINCT log FROM t1 ORDER BY log
658 do_test select4-10.2 {
660 SELECT DISTINCT log FROM t1 ORDER BY log LIMIT 4
663 do_test select4-10.3 {
665 SELECT DISTINCT log FROM t1 ORDER BY log LIMIT 0
668 do_test select4-10.4 {
670 SELECT DISTINCT log FROM t1 ORDER BY log LIMIT -1
673 do_test select4-10.5 {
675 SELECT DISTINCT log FROM t1 ORDER BY log LIMIT -1 OFFSET 2
678 do_test select4-10.6 {
680 SELECT DISTINCT log FROM t1 ORDER BY log LIMIT 3 OFFSET 2
683 do_test select4-10.7 {
685 SELECT DISTINCT log FROM t1 ORDER BY +log LIMIT 3 OFFSET 20
688 do_test select4-10.8 {
690 SELECT DISTINCT log FROM t1 ORDER BY log LIMIT 0 OFFSET 3
693 do_test select4-10.9 {
695 SELECT DISTINCT max(n), log FROM t1 ORDER BY +log; -- LIMIT 2 OFFSET 1
699 # Make sure compound SELECTs with wildly different numbers of columns
700 # do not cause assertion faults due to register allocation issues.
702 do_test select4-11.1 {
704 SELECT x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x FROM t2
708 } {1 {SELECTs to the left and right of UNION do not have the same number of result columns}}
709 do_test select4-11.2 {
713 SELECT x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x FROM t2
715 } {1 {SELECTs to the left and right of UNION do not have the same number of result columns}}
716 do_test select4-11.3 {
718 SELECT x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x FROM t2
722 } {1 {SELECTs to the left and right of UNION ALL do not have the same number of result columns}}
723 do_test select4-11.4 {
727 SELECT x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x FROM t2
729 } {1 {SELECTs to the left and right of UNION ALL do not have the same number of result columns}}
730 do_test select4-11.5 {
732 SELECT x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x FROM t2
736 } {1 {SELECTs to the left and right of EXCEPT do not have the same number of result columns}}
737 do_test select4-11.6 {
741 SELECT x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x FROM t2
743 } {1 {SELECTs to the left and right of EXCEPT do not have the same number of result columns}}
744 do_test select4-11.7 {
746 SELECT x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x FROM t2
750 } {1 {SELECTs to the left and right of INTERSECT do not have the same number of result columns}}
751 do_test select4-11.8 {
755 SELECT x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x FROM t2
757 } {1 {SELECTs to the left and right of INTERSECT do not have the same number of result columns}}
759 do_test select4-11.11 {
769 SELECT x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x FROM t2
771 } {1 {SELECTs to the left and right of INTERSECT do not have the same number of result columns}}
772 do_test select4-11.12 {
780 SELECT x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x FROM t2
784 } {1 {SELECTs to the left and right of EXCEPT do not have the same number of result columns}}
785 do_test select4-11.13 {
791 SELECT x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x FROM t2
797 } {1 {SELECTs to the left and right of UNION ALL do not have the same number of result columns}}
798 do_test select4-11.14 {
802 SELECT x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x FROM t2
810 } {1 {SELECTs to the left and right of UNION do not have the same number of result columns}}
811 do_test select4-11.15 {
813 SELECT x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x FROM t2
823 } {1 {SELECTs to the left and right of UNION do not have the same number of result columns}}
824 do_test select4-11.16 {
826 INSERT INTO t2(rowid) VALUES(2) UNION SELECT 3,4 UNION SELECT 5,6 ORDER BY 1;
828 } {1 {SELECTs to the left and right of UNION do not have the same number of result columns}}
830 do_test select4-12.1 {
833 SELECT 1 UNION SELECT 2,3 UNION SELECT 4,5 ORDER BY 1;
835 } {1 {SELECTs to the left and right of UNION do not have the same number of result columns}}
837 } ;# ifcapable compound
840 # Ticket [3557ad65a076c] - Incorrect DISTINCT processing with an
841 # indexed query using IN.
843 do_test select4-13.1 {
846 CREATE TABLE t13(a,b);
847 INSERT INTO t13 VALUES(1,1);
848 INSERT INTO t13 VALUES(2,1);
849 INSERT INTO t13 VALUES(3,1);
850 INSERT INTO t13 VALUES(2,2);
851 INSERT INTO t13 VALUES(3,2);
852 INSERT INTO t13 VALUES(4,2);
853 CREATE INDEX t13ab ON t13(a,b);
854 SELECT DISTINCT b from t13 WHERE a IN (1,2,3);
858 # 2014-02-18: Make sure compound SELECTs work with VALUES clauses
860 do_execsql_test select4-14.1 {
861 CREATE TABLE t14(a,b,c);
862 INSERT INTO t14 VALUES(1,2,3),(4,5,6);
863 SELECT * FROM t14 INTERSECT VALUES(3,2,1),(2,3,1),(1,2,3),(2,1,3);
865 do_execsql_test select4-14.2 {
866 SELECT * FROM t14 INTERSECT VALUES(1,2,3);
868 do_execsql_test select4-14.3 {
870 UNION VALUES(3,2,1),(2,3,1),(1,2,3),(7,8,9),(4,5,6)
871 UNION SELECT * FROM t14 ORDER BY 1, 2, 3
872 } {1 2 3 2 3 1 3 2 1 4 5 6 7 8 9}
873 do_execsql_test select4-14.4 {
876 UNION SELECT * FROM t14 ORDER BY 1, 2, 3
877 } {1 2 3 3 2 1 4 5 6}
878 do_execsql_test select4-14.5 {
879 SELECT * FROM t14 EXCEPT VALUES(3,2,1),(2,3,1),(1,2,3),(2,1,3);
881 do_execsql_test select4-14.6 {
882 SELECT * FROM t14 EXCEPT VALUES(1,2,3)
884 do_execsql_test select4-14.7 {
885 SELECT * FROM t14 EXCEPT VALUES(1,2,3) EXCEPT VALUES(4,5,6)
887 do_execsql_test select4-14.8 {
888 SELECT * FROM t14 EXCEPT VALUES('a','b','c') EXCEPT VALUES(4,5,6)
890 do_execsql_test select4-14.9 {
891 SELECT * FROM t14 UNION ALL VALUES(3,2,1),(2,3,1),(1,2,3),(2,1,3);
892 } {1 2 3 4 5 6 3 2 1 2 3 1 1 2 3 2 1 3}
893 do_execsql_test select4-14.10 {
894 SELECT (VALUES(1),(2),(3),(4))
896 do_execsql_test select4-14.11 {
897 SELECT (SELECT 1 UNION ALL SELECT 2 UNION ALL SELECT 3 UNION ALL SELECT 4)
899 do_execsql_test select4-14.12 {
900 VALUES(1) UNION VALUES(2);
902 do_execsql_test select4-14.13 {
903 VALUES(1),(2),(3) EXCEPT VALUES(2);
905 do_execsql_test select4-14.14 {
906 VALUES(1),(2),(3) EXCEPT VALUES(1),(3);
908 do_execsql_test select4-14.15 {
909 SELECT * FROM (SELECT 123), (SELECT 456) ON likely(0 OR 1) OR 0;
911 do_execsql_test select4-14.16 {
912 VALUES(1),(2),(3),(4) UNION ALL SELECT 5 LIMIT 99;
914 do_execsql_test select4-14.17 {
915 VALUES(1),(2),(3),(4) UNION ALL SELECT 5 LIMIT 3;
918 # Ticket https://www.sqlite.org/src/info/d06a25c84454a372
919 # Incorrect answer due to two co-routines using the same registers and expecting
920 # those register values to be preserved across a Yield.
922 do_execsql_test select4-15.1 {
923 DROP TABLE IF EXISTS tx;
924 CREATE TABLE tx(id INTEGER PRIMARY KEY, a, b);
925 INSERT INTO tx(a,b) VALUES(33,456);
926 INSERT INTO tx(a,b) VALUES(33,789);
928 SELECT DISTINCT t0.id, t0.a, t0.b
929 FROM tx AS t0, tx AS t1
930 WHERE t0.a=t1.a AND t1.a=33 AND t0.b=456
932 SELECT DISTINCT t0.id, t0.a, t0.b
933 FROM tx AS t0, tx AS t1
934 WHERE t0.a=t1.a AND t1.a=33 AND t0.b=789
936 } {1 33 456 2 33 789}
938 # Enhancement (2016-03-15): Use a co-routine for subqueries if the
939 # subquery is guaranteed to be the outer-most query
941 do_execsql_test select4-16.1 {
942 DROP TABLE IF EXISTS t1;
943 CREATE TABLE t1(a,b,c,d,e,f,g,h,i,j,k,l,m,n,o,p,q,r,s,t,u,v,w,x,y,z,
944 PRIMARY KEY(a,b DESC)) WITHOUT ROWID;
946 WITH RECURSIVE c(x) AS (VALUES(1) UNION ALL SELECT x+1 FROM c WHERE x<100)
947 INSERT INTO t1(a,b,c,d)
948 SELECT x%10, x/10, x, printf('xyz%dabc',x) FROM c;
951 (SELECT a,max(b) AS m FROM t1 WHERE a>=5 GROUP BY a) AS t2
953 WHERE t2.a=t3.a AND t2.m=t3.b
956 do_execsql_test select4-16.2 {
958 (SELECT a,max(b) AS m FROM t1 WHERE a>=5 GROUP BY a) AS t2
960 WHERE t2.a=t3.a AND t2.m=t3.b
963 do_execsql_test select4-16.3 {
965 (SELECT a,max(b) AS m FROM t1 WHERE a>=5 GROUP BY a) AS t2
967 WHERE t2.a=t3.a AND t2.m=t3.b
971 # Ticket https://www.sqlite.org/src/tktview/f7f8c97e975978d45 on 2016-04-25
973 # The where push-down optimization from 2015-06-02 is suppose to disable
974 # on aggregate subqueries. But if the subquery is a compound where the
975 # last SELECT is non-aggregate but some other SELECT is an aggregate, the
976 # test is incomplete and the optimization is not properly disabled.
978 # The following test cases verify that the fix works.
980 do_execsql_test select4-17.1 {
981 DROP TABLE IF EXISTS t1;
982 CREATE TABLE t1(a int, b int);
983 INSERT INTO t1 VALUES(1,2),(1,18),(2,19);
985 SELECT 98 AS x, 99 AS y
987 SELECT a AS x, sum(b) AS y FROM t1 GROUP BY a
991 do_execsql_test select4-17.2 {
993 SELECT a AS x, sum(b) AS y FROM t1 GROUP BY a
995 SELECT 98 AS x, 99 AS y
999 do_catchsql_test select4-17.3 {
1001 SELECT a AS x, sum(b) AS y FROM t1 GROUP BY a LIMIT 3
1003 SELECT 98 AS x, 99 AS y
1006 } {1 {LIMIT clause should come after UNION not before}}
1008 # 2020-04-03 ticket 51166be0159fd2ce from Yong Heng.
1009 # Adverse interaction between the constant propagation and push-down
1013 do_execsql_test select4-18.1 {
1014 CREATE VIEW v0(v0) AS WITH v0 AS(SELECT 0 v0) SELECT(SELECT min(v0) OVER()) FROM v0 GROUP BY v0;
1015 SELECT *FROM v0 v1 JOIN v0 USING(v0) WHERE datetime(v0) = (v0.v0)AND v0 = 10;
1017 do_execsql_test select4-18.2 {
1018 CREATE VIEW t1(aa) AS
1019 WITH t2(bb) AS (SELECT 123)
1020 SELECT (SELECT min(bb) OVER()) FROM t2 GROUP BY bb;
1023 do_execsql_test select4-18.3 {
1024 SELECT * FROM t1 AS z1 JOIN t1 AS z2 USING(aa)
1025 WHERE abs(z1.aa)=z2.aa AND z1.aa=123;
1028 # 2021-03-31 Fix an assert() problem in the logic at the end of sqlite3Select()
1029 # that validates AggInfo. The checks to ensure that AggInfo.aCol[].pCExpr
1030 # references a valid expression was looking at an expression that had been
1031 # deleted by the truth optimization in sqlite3ExprAnd() which was invoked by
1032 # the push-down optimization. This is harmless in delivery builds, as that code
1033 # only runs with SQLITE_DEBUG. But it should still be fixed. The problem
1034 # was discovered by dbsqlfuzz (crash-dece7b67a3552ed7e571a7bda903afd1f7bd9b21)
1037 do_execsql_test select4-19.1 {
1039 INSERT INTO t1 VALUES(99);
1040 SELECT sum((SELECT 1 FROM (SELECT 2 WHERE x IS NULL) WHERE 0)) FROM t1;