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 script is testing correlated subqueries
16 set testdir [file dirname $argv0]
17 source $testdir/tester.tcl
18 set ::testprefix subquery2
25 do_test subquery2-1.1 {
29 INSERT INTO t1 VALUES(1,2);
30 INSERT INTO t1 VALUES(3,4);
31 INSERT INTO t1 VALUES(5,6);
32 INSERT INTO t1 VALUES(7,8);
34 INSERT INTO t2 VALUES(1,1);
35 INSERT INTO t2 VALUES(3,9);
36 INSERT INTO t2 VALUES(5,25);
37 INSERT INTO t2 VALUES(7,49);
39 INSERT INTO t3 VALUES(1,1);
40 INSERT INTO t3 VALUES(3,27);
41 INSERT INTO t3 VALUES(5,125);
42 INSERT INTO t3 VALUES(7,343);
47 WHERE b IN (SELECT x+1 FROM (SELECT DISTINCT f/(a*a) AS x FROM t3));
50 do_test subquery2-1.2 {
52 CREATE INDEX t1b ON t1(b);
54 WHERE b IN (SELECT x+1 FROM (SELECT DISTINCT f/(a*a) AS x FROM t3));
58 do_test subquery2-1.11 {
61 WHERE +b=(SELECT x+1 FROM (SELECT DISTINCT f/(a*a) AS x FROM t3));
64 do_test subquery2-1.12 {
67 WHERE b=(SELECT x+1 FROM (SELECT DISTINCT f/(a*a) AS x FROM t3));
71 do_test subquery2-1.21 {
74 WHERE +b=(SELECT x+1 FROM
75 (SELECT DISTINCT f/d AS x FROM t2 JOIN t3 ON d*a=f))
78 do_test subquery2-1.22 {
81 WHERE b=(SELECT x+1 FROM
82 (SELECT DISTINCT f/d AS x FROM t2 JOIN t3 ON d*a=f))
86 #-------------------------------------------------------------------------
87 # Test that ticket d6b36be38a has been fixed.
89 CREATE TABLE t4(a, b);
90 CREATE TABLE t5(a, b);
91 INSERT INTO t5 VALUES(3, 5);
93 INSERT INTO t4 VALUES(1, 1);
94 INSERT INTO t4 VALUES(2, 3);
95 INSERT INTO t4 VALUES(3, 6);
96 INSERT INTO t4 VALUES(4, 10);
97 INSERT INTO t4 VALUES(5, 15);
100 do_execsql_test 2.2 {
102 FROM (SELECT * FROM t4 ORDER BY a LIMIT -1 OFFSET 1)
103 LIMIT (SELECT a FROM t5)
106 ############################################################################
107 # Ticket http://www.sqlite.org/src/info/d11a6e908f (2014-09-20)
108 # Query planner fault on three-way nested join with compound inner SELECT
110 do_execsql_test 3.0 {
111 DROP TABLE IF EXISTS t1;
112 DROP TABLE IF EXISTS t2;
113 CREATE TABLE t1 (id INTEGER PRIMARY KEY, data TEXT);
114 INSERT INTO t1(id,data) VALUES(9,'nine-a');
115 INSERT INTO t1(id,data) VALUES(10,'ten-a');
116 INSERT INTO t1(id,data) VALUES(11,'eleven-a');
117 CREATE TABLE t2 (id INTEGER PRIMARY KEY, data TEXT);
118 INSERT INTO t2(id,data) VALUES(9,'nine-b');
119 INSERT INTO t2(id,data) VALUES(10,'ten-b');
120 INSERT INTO t2(id,data) VALUES(11,'eleven-b');
123 SELECT id,data FROM (
124 SELECT * FROM t1 UNION ALL SELECT * FROM t2
126 WHERE id=10 ORDER BY data
129 do_execsql_test 3.1 {
131 SELECT 'dummy', data FROM (
132 SELECT data FROM t1 UNION ALL SELECT data FROM t1
135 } {eleven-a eleven-a nine-a nine-a ten-a ten-a}
136 do_execsql_test 3.2 {
137 DROP TABLE IF EXISTS t3;
138 DROP TABLE IF EXISTS t4;
139 CREATE TABLE t3(id INTEGER, data TEXT);
140 CREATE TABLE t4(id INTEGER, data TEXT);
141 INSERT INTO t3 VALUES(4, 'a'),(2,'c');
142 INSERT INTO t4 VALUES(3, 'b'),(1,'d');
144 SELECT data, id FROM (
145 SELECT id, data FROM (
146 SELECT * FROM t3 UNION ALL SELECT * FROM t4