xref: /sqlite-3.40.0/test/select6.test (revision 7d44b22d)
1d820cb1bSdrh# 2001 September 15
2d820cb1bSdrh#
3d820cb1bSdrh# The author disclaims copyright to this source code.  In place of
4d820cb1bSdrh# a legal notice, here is a blessing:
5d820cb1bSdrh#
6d820cb1bSdrh#    May you do good and not evil.
7d820cb1bSdrh#    May you find forgiveness for yourself and forgive others.
8d820cb1bSdrh#    May you share freely, never taking more than you give.
9d820cb1bSdrh#
10d820cb1bSdrh#***********************************************************************
11d820cb1bSdrh# This file implements regression tests for SQLite library.  The
12d820cb1bSdrh# focus of this file is testing SELECT statements that contain
13d820cb1bSdrh# subqueries in their FROM clause.
14d820cb1bSdrh#
15d820cb1bSdrh
16d820cb1bSdrhset testdir [file dirname $argv0]
17d820cb1bSdrhsource $testdir/tester.tcl
18d820cb1bSdrh
193e8c37e7Sdanielk1977# Omit this whole file if the library is build without subquery support.
203e8c37e7Sdanielk1977ifcapable !subquery {
213e8c37e7Sdanielk1977  finish_test
223e8c37e7Sdanielk1977  return
233e8c37e7Sdanielk1977}
2467c70142Sdanset ::testprefix select6
253e8c37e7Sdanielk1977
26d820cb1bSdrhdo_test select6-1.0 {
27cf909506Sdrh  execsql {
28cf909506Sdrh    BEGIN;
29cf909506Sdrh    CREATE TABLE t1(x, y);
30cf909506Sdrh    INSERT INTO t1 VALUES(1,1);
31cf909506Sdrh    INSERT INTO t1 VALUES(2,2);
32cf909506Sdrh    INSERT INTO t1 VALUES(3,2);
33cf909506Sdrh    INSERT INTO t1 VALUES(4,3);
34cf909506Sdrh    INSERT INTO t1 VALUES(5,3);
35cf909506Sdrh    INSERT INTO t1 VALUES(6,3);
36cf909506Sdrh    INSERT INTO t1 VALUES(7,3);
37cf909506Sdrh    INSERT INTO t1 VALUES(8,4);
38cf909506Sdrh    INSERT INTO t1 VALUES(9,4);
39cf909506Sdrh    INSERT INTO t1 VALUES(10,4);
40cf909506Sdrh    INSERT INTO t1 VALUES(11,4);
41cf909506Sdrh    INSERT INTO t1 VALUES(12,4);
42cf909506Sdrh    INSERT INTO t1 VALUES(13,4);
43cf909506Sdrh    INSERT INTO t1 VALUES(14,4);
44cf909506Sdrh    INSERT INTO t1 VALUES(15,4);
45cf909506Sdrh    INSERT INTO t1 VALUES(16,5);
46cf909506Sdrh    INSERT INTO t1 VALUES(17,5);
47cf909506Sdrh    INSERT INTO t1 VALUES(18,5);
48cf909506Sdrh    INSERT INTO t1 VALUES(19,5);
49cf909506Sdrh    INSERT INTO t1 VALUES(20,5);
50cf909506Sdrh    COMMIT;
51cf909506Sdrh    SELECT DISTINCT y FROM t1 ORDER BY y;
52cf909506Sdrh  }
53cf909506Sdrh} {1 2 3 4 5}
54d820cb1bSdrh
55d820cb1bSdrhdo_test select6-1.1 {
56cf909506Sdrh  execsql2 {SELECT * FROM (SELECT x, y FROM t1 WHERE x<2)}
57cf909506Sdrh} {x 1 y 1}
58d820cb1bSdrhdo_test select6-1.2 {
59d820cb1bSdrh  execsql {SELECT count(*) FROM (SELECT y FROM t1)}
60cf909506Sdrh} {20}
61d820cb1bSdrhdo_test select6-1.3 {
62d820cb1bSdrh  execsql {SELECT count(*) FROM (SELECT DISTINCT y FROM t1)}
63cf909506Sdrh} {5}
64d820cb1bSdrhdo_test select6-1.4 {
65d820cb1bSdrh  execsql {SELECT count(*) FROM (SELECT DISTINCT * FROM (SELECT y FROM t1))}
66cf909506Sdrh} {5}
67d820cb1bSdrhdo_test select6-1.5 {
68d820cb1bSdrh  execsql {SELECT count(*) FROM (SELECT * FROM (SELECT DISTINCT y FROM t1))}
69cf909506Sdrh} {5}
70d820cb1bSdrh
71cf909506Sdrhdo_test select6-1.6 {
72cf909506Sdrh  execsql {
73cf909506Sdrh    SELECT *
74cf909506Sdrh    FROM (SELECT count(*),y FROM t1 GROUP BY y) AS a,
75cf909506Sdrh         (SELECT max(x),y FROM t1 GROUP BY y) as b
76cf909506Sdrh    WHERE a.y=b.y ORDER BY a.y
77cf909506Sdrh  }
78cf909506Sdrh} {1 1 1 1 2 2 3 2 4 3 7 3 8 4 15 4 5 5 20 5}
79cf909506Sdrhdo_test select6-1.7 {
80cf909506Sdrh  execsql {
81cf909506Sdrh    SELECT a.y, a.[count(*)], [max(x)], [count(*)]
82cf909506Sdrh    FROM (SELECT count(*),y FROM t1 GROUP BY y) AS a,
83cf909506Sdrh         (SELECT max(x),y FROM t1 GROUP BY y) as b
84cf909506Sdrh    WHERE a.y=b.y ORDER BY a.y
85cf909506Sdrh  }
86cf909506Sdrh} {1 1 1 1 2 2 3 2 3 4 7 4 4 8 15 8 5 5 20 5}
87cf909506Sdrhdo_test select6-1.8 {
88cf909506Sdrh  execsql {
89cf909506Sdrh    SELECT q, p, r
90cf909506Sdrh    FROM (SELECT count(*) as p , y as q FROM t1 GROUP BY y) AS a,
91cf909506Sdrh         (SELECT max(x) as r, y as s FROM t1 GROUP BY y) as b
92cf909506Sdrh    WHERE q=s ORDER BY s
93cf909506Sdrh  }
94cf909506Sdrh} {1 1 1 2 2 3 3 4 7 4 8 15 5 5 20}
95cf909506Sdrhdo_test select6-1.9 {
96cf909506Sdrh  execsql {
97cf909506Sdrh    SELECT q, p, r, b.[min(x)+y]
98cf909506Sdrh    FROM (SELECT count(*) as p , y as q FROM t1 GROUP BY y) AS a,
99cf909506Sdrh         (SELECT max(x) as r, y as s, min(x)+y FROM t1 GROUP BY y) as b
100cf909506Sdrh    WHERE q=s ORDER BY s
101cf909506Sdrh  }
102cf909506Sdrh} {1 1 1 2 2 2 3 4 3 4 7 7 4 8 15 12 5 5 20 21}
103d820cb1bSdrh
104741f7063Sdrhdo_test select6-2.0 {
105cf909506Sdrh  execsql {
106cf909506Sdrh    CREATE TABLE t2(a INTEGER PRIMARY KEY, b);
107cf909506Sdrh    INSERT INTO t2 SELECT * FROM t1;
108cf909506Sdrh    SELECT DISTINCT b FROM t2 ORDER BY b;
109cf909506Sdrh  }
110cf909506Sdrh} {1 2 3 4 5}
111cf909506Sdrhdo_test select6-2.1 {
112cf909506Sdrh  execsql2 {SELECT * FROM (SELECT a, b FROM t2 WHERE a<2)}
113cf909506Sdrh} {a 1 b 1}
114cf909506Sdrhdo_test select6-2.2 {
115cf909506Sdrh  execsql {SELECT count(*) FROM (SELECT b FROM t2)}
116cf909506Sdrh} {20}
117cf909506Sdrhdo_test select6-2.3 {
118cf909506Sdrh  execsql {SELECT count(*) FROM (SELECT DISTINCT b FROM t2)}
119cf909506Sdrh} {5}
120cf909506Sdrhdo_test select6-2.4 {
121cf909506Sdrh  execsql {SELECT count(*) FROM (SELECT DISTINCT * FROM (SELECT b FROM t2))}
122cf909506Sdrh} {5}
123cf909506Sdrhdo_test select6-2.5 {
124cf909506Sdrh  execsql {SELECT count(*) FROM (SELECT * FROM (SELECT DISTINCT b FROM t2))}
125cf909506Sdrh} {5}
126d820cb1bSdrh
127cf909506Sdrhdo_test select6-2.6 {
128cf909506Sdrh  execsql {
129cf909506Sdrh    SELECT *
130cf909506Sdrh    FROM (SELECT count(*),b FROM t2 GROUP BY b) AS a,
131cf909506Sdrh         (SELECT max(a),b FROM t2 GROUP BY b) as b
132cf909506Sdrh    WHERE a.b=b.b ORDER BY a.b
133cf909506Sdrh  }
134cf909506Sdrh} {1 1 1 1 2 2 3 2 4 3 7 3 8 4 15 4 5 5 20 5}
135cf909506Sdrhdo_test select6-2.7 {
136cf909506Sdrh  execsql {
137cf909506Sdrh    SELECT a.b, a.[count(*)], [max(a)], [count(*)]
138cf909506Sdrh    FROM (SELECT count(*),b FROM t2 GROUP BY b) AS a,
139cf909506Sdrh         (SELECT max(a),b FROM t2 GROUP BY b) as b
140cf909506Sdrh    WHERE a.b=b.b ORDER BY a.b
141cf909506Sdrh  }
142cf909506Sdrh} {1 1 1 1 2 2 3 2 3 4 7 4 4 8 15 8 5 5 20 5}
143cf909506Sdrhdo_test select6-2.8 {
144cf909506Sdrh  execsql {
145cf909506Sdrh    SELECT q, p, r
146cf909506Sdrh    FROM (SELECT count(*) as p , b as q FROM t2 GROUP BY b) AS a,
147cf909506Sdrh         (SELECT max(a) as r, b as s FROM t2 GROUP BY b) as b
148cf909506Sdrh    WHERE q=s ORDER BY s
149cf909506Sdrh  }
150cf909506Sdrh} {1 1 1 2 2 3 3 4 7 4 8 15 5 5 20}
151cf909506Sdrhdo_test select6-2.9 {
152cf909506Sdrh  execsql {
153cf909506Sdrh    SELECT a.q, a.p, b.r
154cf909506Sdrh    FROM (SELECT count(*) as p , b as q FROM t2 GROUP BY q) AS a,
155cf909506Sdrh         (SELECT max(a) as r, b as s FROM t2 GROUP BY s) as b
156cf909506Sdrh    WHERE a.q=b.s ORDER BY a.q
157cf909506Sdrh  }
158cf909506Sdrh} {1 1 1 2 2 3 3 4 7 4 8 15 5 5 20}
159cf909506Sdrh
160b3bce662Sdanielk1977do_test select6-3.1 {
161cf909506Sdrh  execsql2 {
162cf909506Sdrh    SELECT * FROM (SELECT * FROM (SELECT * FROM t1 WHERE x=3));
163cf909506Sdrh  }
164cf909506Sdrh} {x 3 y 2}
165b3bce662Sdanielk1977do_test select6-3.2 {
166cf909506Sdrh  execsql {
167cf909506Sdrh    SELECT * FROM
168cf909506Sdrh      (SELECT a.q, a.p, b.r
169cf909506Sdrh       FROM (SELECT count(*) as p , b as q FROM t2 GROUP BY q) AS a,
170cf909506Sdrh            (SELECT max(a) as r, b as s FROM t2 GROUP BY s) as b
171cf909506Sdrh       WHERE a.q=b.s ORDER BY a.q)
172cf909506Sdrh  }
173cf909506Sdrh} {1 1 1 2 2 3 3 4 7 4 8 15 5 5 20}
1741b2e0329Sdrhdo_test select6-3.3 {
1751b2e0329Sdrh  execsql {
1761b2e0329Sdrh    SELECT a,b,a+b FROM (SELECT avg(x) as 'a', avg(y) as 'b' FROM t1)
1771b2e0329Sdrh  }
1781b2e0329Sdrh} {10.5 3.7 14.2}
1791b2e0329Sdrhdo_test select6-3.4 {
1801b2e0329Sdrh  execsql {
1811b2e0329Sdrh    SELECT a,b,a+b FROM (SELECT avg(x) as 'a', avg(y) as 'b' FROM t1 WHERE y=4)
1821b2e0329Sdrh  }
18392febd92Sdrh} {11.5 4.0 15.5}
1841b2e0329Sdrhdo_test select6-3.5 {
1851b2e0329Sdrh  execsql {
1861b2e0329Sdrh    SELECT x,y,x+y FROM (SELECT avg(a) as 'x', avg(b) as 'y' FROM t2 WHERE a=4)
1871b2e0329Sdrh  }
1888a51256cSdrh} {4.0 3.0 7.0}
1891b2e0329Sdrhdo_test select6-3.6 {
1901b2e0329Sdrh  execsql {
1911b2e0329Sdrh    SELECT a,b,a+b FROM (SELECT avg(x) as 'a', avg(y) as 'b' FROM t1)
1921b2e0329Sdrh    WHERE a>10
1931b2e0329Sdrh  }
1941b2e0329Sdrh} {10.5 3.7 14.2}
1951b2e0329Sdrhdo_test select6-3.7 {
1961b2e0329Sdrh  execsql {
1971b2e0329Sdrh    SELECT a,b,a+b FROM (SELECT avg(x) as 'a', avg(y) as 'b' FROM t1)
1981b2e0329Sdrh    WHERE a<10
1991b2e0329Sdrh  }
2001b2e0329Sdrh} {}
2011b2e0329Sdrhdo_test select6-3.8 {
2021b2e0329Sdrh  execsql {
2031b2e0329Sdrh    SELECT a,b,a+b FROM (SELECT avg(x) as 'a', avg(y) as 'b' FROM t1 WHERE y=4)
2041b2e0329Sdrh    WHERE a>10
2051b2e0329Sdrh  }
20692febd92Sdrh} {11.5 4.0 15.5}
2071b2e0329Sdrhdo_test select6-3.9 {
2081b2e0329Sdrh  execsql {
2091b2e0329Sdrh    SELECT a,b,a+b FROM (SELECT avg(x) as 'a', avg(y) as 'b' FROM t1 WHERE y=4)
2101b2e0329Sdrh    WHERE a<10
2111b2e0329Sdrh  }
2121b2e0329Sdrh} {}
2131b2e0329Sdrhdo_test select6-3.10 {
2141b2e0329Sdrh  execsql {
2151b2e0329Sdrh    SELECT a,b,a+b FROM (SELECT avg(x) as 'a', y as 'b' FROM t1 GROUP BY b)
2161b2e0329Sdrh    ORDER BY a
2171b2e0329Sdrh  }
2188a51256cSdrh} {1.0 1 2.0 2.5 2 4.5 5.5 3 8.5 11.5 4 15.5 18.0 5 23.0}
2191b2e0329Sdrhdo_test select6-3.11 {
2201b2e0329Sdrh  execsql {
2211b2e0329Sdrh    SELECT a,b,a+b FROM
2221b2e0329Sdrh       (SELECT avg(x) as 'a', y as 'b' FROM t1 GROUP BY b)
2231b2e0329Sdrh    WHERE b<4 ORDER BY a
2241b2e0329Sdrh  }
2258a51256cSdrh} {1.0 1 2.0 2.5 2 4.5 5.5 3 8.5}
2261b2e0329Sdrhdo_test select6-3.12 {
2271b2e0329Sdrh  execsql {
2281b2e0329Sdrh    SELECT a,b,a+b FROM
2291b2e0329Sdrh       (SELECT avg(x) as 'a', y as 'b' FROM t1 GROUP BY b HAVING a>1)
2301b2e0329Sdrh    WHERE b<4 ORDER BY a
2311b2e0329Sdrh  }
2321b2e0329Sdrh} {2.5 2 4.5 5.5 3 8.5}
2331b2e0329Sdrhdo_test select6-3.13 {
2341b2e0329Sdrh  execsql {
2351b2e0329Sdrh    SELECT a,b,a+b FROM
2361b2e0329Sdrh       (SELECT avg(x) as 'a', y as 'b' FROM t1 GROUP BY b HAVING a>1)
2371b2e0329Sdrh    ORDER BY a
2381b2e0329Sdrh  }
2398a51256cSdrh} {2.5 2 4.5 5.5 3 8.5 11.5 4 15.5 18.0 5 23.0}
2401b2e0329Sdrhdo_test select6-3.14 {
2411b2e0329Sdrh  execsql {
2421b2e0329Sdrh    SELECT [count(*)],y FROM (SELECT count(*), y FROM t1 GROUP BY y)
2431b2e0329Sdrh    ORDER BY [count(*)]
2441b2e0329Sdrh  }
2451b2e0329Sdrh} {1 1 2 2 4 3 5 5 8 4}
2461b2e0329Sdrhdo_test select6-3.15 {
2471b2e0329Sdrh  execsql {
2481b2e0329Sdrh    SELECT [count(*)],y FROM (SELECT count(*), y FROM t1 GROUP BY y)
2491b2e0329Sdrh    ORDER BY y
2501b2e0329Sdrh  }
2511b2e0329Sdrh} {1 1 2 2 4 3 8 4 5 5}
2521b2e0329Sdrh
2531b2e0329Sdrhdo_test select6-4.1 {
2541b2e0329Sdrh  execsql {
2551b2e0329Sdrh    SELECT a,b,c FROM
2561b2e0329Sdrh      (SELECT x AS 'a', y AS 'b', x+y AS 'c' FROM t1 WHERE y=4)
2571b2e0329Sdrh    WHERE a<10 ORDER BY a;
2581b2e0329Sdrh  }
2591b2e0329Sdrh} {8 4 12 9 4 13}
2601b2e0329Sdrhdo_test select6-4.2 {
2611b2e0329Sdrh  execsql {
2621b2e0329Sdrh    SELECT y FROM (SELECT DISTINCT y FROM t1) WHERE y<5 ORDER BY y
2631b2e0329Sdrh  }
2641b2e0329Sdrh} {1 2 3 4}
2651b2e0329Sdrhdo_test select6-4.3 {
2661b2e0329Sdrh  execsql {
2671b2e0329Sdrh    SELECT DISTINCT y FROM (SELECT y FROM t1) WHERE y<5 ORDER BY y
2681b2e0329Sdrh  }
2691b2e0329Sdrh} {1 2 3 4}
2702d0794e3Sdrhdo_test select6-4.4 {
2712d0794e3Sdrh  execsql {
2722d0794e3Sdrh    SELECT avg(y) FROM (SELECT DISTINCT y FROM t1) WHERE y<5 ORDER BY y
2732d0794e3Sdrh  }
2742d0794e3Sdrh} {2.5}
2752d0794e3Sdrhdo_test select6-4.5 {
2762d0794e3Sdrh  execsql {
2772d0794e3Sdrh    SELECT avg(y) FROM (SELECT DISTINCT y FROM t1 WHERE y<5) ORDER BY y
2782d0794e3Sdrh  }
2792d0794e3Sdrh} {2.5}
2801b2e0329Sdrh
281c0a165b3Sdrhdo_test select6-5.1 {
282c0a165b3Sdrh  execsql {
283c0a165b3Sdrh    SELECT a,x,b FROM
284c0a165b3Sdrh      (SELECT x+3 AS 'a', x FROM t1 WHERE y=3) AS 'p',
285c0a165b3Sdrh      (SELECT x AS 'b' FROM t1 WHERE y=4) AS 'q'
286c0a165b3Sdrh    WHERE a=b
287c0a165b3Sdrh    ORDER BY a
288c0a165b3Sdrh  }
289c0a165b3Sdrh} {8 5 8 9 6 9 10 7 10}
290094b2bbfSdrhdo_test select6-5.2 {
291094b2bbfSdrh  execsql {
292094b2bbfSdrh    SELECT a,x,b FROM
293094b2bbfSdrh      (SELECT x+3 AS 'a', x FROM t1 WHERE y=3),
294094b2bbfSdrh      (SELECT x AS 'b' FROM t1 WHERE y=4)
295094b2bbfSdrh    WHERE a=b
296094b2bbfSdrh    ORDER BY a
297094b2bbfSdrh  }
298094b2bbfSdrh} {8 5 8 9 6 9 10 7 10}
2991b2e0329Sdrh
3001cc3d75fSdrh# Tests of compound sub-selects
3011cc3d75fSdrh#
3027d10d5a6Sdrhdo_test select6-6.1 {
3031cc3d75fSdrh  execsql {
3041cc3d75fSdrh    DELETE FROM t1 WHERE x>4;
3051cc3d75fSdrh    SELECT * FROM t1
3061cc3d75fSdrh  }
3071cc3d75fSdrh} {1 1 2 2 3 2 4 3}
308a1686c9aSdanielk1977ifcapable compound {
3091cc3d75fSdrh  do_test select6-6.2 {
3101cc3d75fSdrh    execsql {
3111cc3d75fSdrh      SELECT * FROM (
3121cc3d75fSdrh        SELECT x AS 'a' FROM t1 UNION ALL SELECT x+10 AS 'a' FROM t1
3131cc3d75fSdrh      ) ORDER BY a;
3141cc3d75fSdrh    }
3151cc3d75fSdrh  } {1 2 3 4 11 12 13 14}
3161cc3d75fSdrh  do_test select6-6.3 {
3171cc3d75fSdrh    execsql {
3181cc3d75fSdrh      SELECT * FROM (
3191cc3d75fSdrh        SELECT x AS 'a' FROM t1 UNION ALL SELECT x+1 AS 'a' FROM t1
3201cc3d75fSdrh      ) ORDER BY a;
3211cc3d75fSdrh    }
3221cc3d75fSdrh  } {1 2 2 3 3 4 4 5}
3231cc3d75fSdrh  do_test select6-6.4 {
3241cc3d75fSdrh    execsql {
3251cc3d75fSdrh      SELECT * FROM (
3261cc3d75fSdrh        SELECT x AS 'a' FROM t1 UNION SELECT x+1 AS 'a' FROM t1
3271cc3d75fSdrh      ) ORDER BY a;
3281cc3d75fSdrh    }
3291cc3d75fSdrh  } {1 2 3 4 5}
3301cc3d75fSdrh  do_test select6-6.5 {
3311cc3d75fSdrh    execsql {
3321cc3d75fSdrh      SELECT * FROM (
3331cc3d75fSdrh        SELECT x AS 'a' FROM t1 INTERSECT SELECT x+1 AS 'a' FROM t1
3341cc3d75fSdrh      ) ORDER BY a;
3351cc3d75fSdrh    }
3361cc3d75fSdrh  } {2 3 4}
3371cc3d75fSdrh  do_test select6-6.6 {
3381cc3d75fSdrh    execsql {
3391cc3d75fSdrh      SELECT * FROM (
3401cc3d75fSdrh        SELECT x AS 'a' FROM t1 EXCEPT SELECT x*2 AS 'a' FROM t1
3411cc3d75fSdrh      ) ORDER BY a;
3421cc3d75fSdrh    }
3431cc3d75fSdrh  } {1 3}
34427c77438Sdanielk1977} ;# ifcapable compound
3451cc3d75fSdrh
34608192d5fSdrh# Subselects with no FROM clause
34708192d5fSdrh#
34808192d5fSdrhdo_test select6-7.1 {
34908192d5fSdrh  execsql {
35008192d5fSdrh    SELECT * FROM (SELECT 1)
35108192d5fSdrh  }
35208192d5fSdrh} {1}
35308192d5fSdrhdo_test select6-7.2 {
35408192d5fSdrh  execsql {
35508192d5fSdrh    SELECT c,b,a,* FROM (SELECT 1 AS 'a', 2 AS 'b', 'abc' AS 'c')
35608192d5fSdrh  }
35708192d5fSdrh} {abc 2 1 1 2 abc}
35808192d5fSdrhdo_test select6-7.3 {
35908192d5fSdrh  execsql {
36008192d5fSdrh    SELECT c,b,a,* FROM (SELECT 1 AS 'a', 2 AS 'b', 'abc' AS 'c' WHERE 0)
36108192d5fSdrh  }
36208192d5fSdrh} {}
36308192d5fSdrhdo_test select6-7.4 {
36408192d5fSdrh  execsql2 {
36508192d5fSdrh    SELECT c,b,a,* FROM (SELECT 1 AS 'a', 2 AS 'b', 'abc' AS 'c' WHERE 1)
36608192d5fSdrh  }
36708192d5fSdrh} {c abc b 2 a 1 a 1 b 2 c abc}
36808192d5fSdrh
3696bf89570Sdrh# The remaining tests in this file depend on the EXPLAIN keyword.
3706bf89570Sdrh# Skip these tests if EXPLAIN is disabled in the current build.
3716bf89570Sdrh#
3726bf89570Sdrhifcapable {!explain} {
3736bf89570Sdrh  finish_test
3746bf89570Sdrh  return
3756bf89570Sdrh}
3766bf89570Sdrh
377e9ffc168Sdrh# The following procedure compiles the SQL given as an argument and returns
378e9ffc168Sdrh# TRUE if that SQL uses any transient tables and returns FALSE if no
379e9ffc168Sdrh# transient tables are used.  This is used to make sure that the
380e9ffc168Sdrh# sqliteFlattenSubquery() routine in select.c is doing its job.
381e9ffc168Sdrh#
382e9ffc168Sdrhproc is_flat {sql} {
383b9bb7c18Sdrh  return [expr 0>[lsearch [execsql "EXPLAIN $sql"] OpenEphemeral]]
384e9ffc168Sdrh}
385e9ffc168Sdrh
386e9ffc168Sdrh# Check that the flattener works correctly for deeply nested subqueries
387e9ffc168Sdrh# involving joins.
388e9ffc168Sdrh#
389e9ffc168Sdrhdo_test select6-8.1 {
390e9ffc168Sdrh  execsql {
391e9ffc168Sdrh    BEGIN;
392e9ffc168Sdrh    CREATE TABLE t3(p,q);
393e9ffc168Sdrh    INSERT INTO t3 VALUES(1,11);
394e9ffc168Sdrh    INSERT INTO t3 VALUES(2,22);
395e9ffc168Sdrh    CREATE TABLE t4(q,r);
396e9ffc168Sdrh    INSERT INTO t4 VALUES(11,111);
397e9ffc168Sdrh    INSERT INTO t4 VALUES(22,222);
398e9ffc168Sdrh    COMMIT;
399e9ffc168Sdrh    SELECT * FROM t3 NATURAL JOIN t4;
400e9ffc168Sdrh  }
401e9ffc168Sdrh} {1 11 111 2 22 222}
402e9ffc168Sdrhdo_test select6-8.2 {
403e9ffc168Sdrh  execsql {
404e9ffc168Sdrh    SELECT y, p, q, r FROM
405e9ffc168Sdrh       (SELECT t1.y AS y, t2.b AS b FROM t1, t2 WHERE t1.x=t2.a) AS m,
406e9ffc168Sdrh       (SELECT t3.p AS p, t3.q AS q, t4.r AS r FROM t3 NATURAL JOIN t4) as n
407e9ffc168Sdrh    WHERE  y=p
408e9ffc168Sdrh  }
409e9ffc168Sdrh} {1 1 11 111 2 2 22 222 2 2 22 222}
410d8702b4dSdanielk1977# If view support is omitted from the build, then so is the query
411d8702b4dSdanielk1977# "flattener". So omit this test and test select6-8.6 in that case.
412d8702b4dSdanielk1977ifcapable view {
413e9ffc168Sdrhdo_test select6-8.3 {
414e9ffc168Sdrh  is_flat {
415e9ffc168Sdrh    SELECT y, p, q, r FROM
416e9ffc168Sdrh       (SELECT t1.y AS y, t2.b AS b FROM t1, t2 WHERE t1.x=t2.a) AS m,
417e9ffc168Sdrh       (SELECT t3.p AS p, t3.q AS q, t4.r AS r FROM t3 NATURAL JOIN t4) as n
418e9ffc168Sdrh    WHERE  y=p
419e9ffc168Sdrh  }
420e9ffc168Sdrh} {1}
421d8702b4dSdanielk1977} ;# ifcapable view
422e9ffc168Sdrhdo_test select6-8.4 {
423e9ffc168Sdrh  execsql {
424e9ffc168Sdrh    SELECT DISTINCT y, p, q, r FROM
425e9ffc168Sdrh       (SELECT t1.y AS y, t2.b AS b FROM t1, t2 WHERE t1.x=t2.a) AS m,
426e9ffc168Sdrh       (SELECT t3.p AS p, t3.q AS q, t4.r AS r FROM t3 NATURAL JOIN t4) as n
427e9ffc168Sdrh    WHERE  y=p
428e9ffc168Sdrh  }
429e9ffc168Sdrh} {1 1 11 111 2 2 22 222}
430e9ffc168Sdrhdo_test select6-8.5 {
431e9ffc168Sdrh  execsql {
432e9ffc168Sdrh    SELECT * FROM
433e9ffc168Sdrh      (SELECT y, p, q, r FROM
434e9ffc168Sdrh         (SELECT t1.y AS y, t2.b AS b FROM t1, t2 WHERE t1.x=t2.a) AS m,
435e9ffc168Sdrh         (SELECT t3.p AS p, t3.q AS q, t4.r AS r FROM t3 NATURAL JOIN t4) as n
436e9ffc168Sdrh      WHERE  y=p) AS e,
437e9ffc168Sdrh      (SELECT r AS z FROM t4 WHERE q=11) AS f
438e9ffc168Sdrh    WHERE e.r=f.z
439e9ffc168Sdrh  }
440e9ffc168Sdrh} {1 1 11 111 111}
441d8702b4dSdanielk1977ifcapable view {
442e9ffc168Sdrhdo_test select6-8.6 {
443e9ffc168Sdrh  is_flat {
444e9ffc168Sdrh    SELECT * FROM
445e9ffc168Sdrh      (SELECT y, p, q, r FROM
446e9ffc168Sdrh         (SELECT t1.y AS y, t2.b AS b FROM t1, t2 WHERE t1.x=t2.a) AS m,
447e9ffc168Sdrh         (SELECT t3.p AS p, t3.q AS q, t4.r AS r FROM t3 NATURAL JOIN t4) as n
448e9ffc168Sdrh      WHERE  y=p) AS e,
449e9ffc168Sdrh      (SELECT r AS z FROM t4 WHERE q=11) AS f
450e9ffc168Sdrh    WHERE e.r=f.z
451e9ffc168Sdrh  }
452e9ffc168Sdrh} {1}
453d8702b4dSdanielk1977} ;# ifcapable view
454e9ffc168Sdrh
455fe61378aSdrh# Ticket #1634
456fe61378aSdrh#
457fe61378aSdrhdo_test select6-9.1 {
458fe61378aSdrh  execsql {
459fe61378aSdrh    SELECT a.x, b.x FROM t1 AS a, (SELECT x FROM t1 LIMIT 2) AS b
46015564055Sdrh     ORDER BY 1, 2
461fe61378aSdrh  }
462fe61378aSdrh} {1 1 1 2 2 1 2 2 3 1 3 2 4 1 4 2}
463fe61378aSdrhdo_test select6-9.2 {
464fe61378aSdrh  execsql {
465fe61378aSdrh    SELECT x FROM (SELECT x FROM t1 LIMIT 2);
466fe61378aSdrh  }
467fe61378aSdrh} {1 2}
468fe61378aSdrhdo_test select6-9.3 {
469fe61378aSdrh  execsql {
470fe61378aSdrh    SELECT x FROM (SELECT x FROM t1 LIMIT 2 OFFSET 1);
471fe61378aSdrh  }
472fe61378aSdrh} {2 3}
473fe61378aSdrhdo_test select6-9.4 {
474fe61378aSdrh  execsql {
475fe61378aSdrh    SELECT x FROM (SELECT x FROM t1) LIMIT 2;
476fe61378aSdrh  }
477fe61378aSdrh} {1 2}
478fe61378aSdrhdo_test select6-9.5 {
479fe61378aSdrh  execsql {
480fe61378aSdrh    SELECT x FROM (SELECT x FROM t1) LIMIT 2 OFFSET 1;
481fe61378aSdrh  }
482fe61378aSdrh} {2 3}
483fe61378aSdrhdo_test select6-9.6 {
484fe61378aSdrh  execsql {
485fe61378aSdrh    SELECT x FROM (SELECT x FROM t1 LIMIT 2) LIMIT 3;
486fe61378aSdrh  }
487fe61378aSdrh} {1 2}
488fe61378aSdrhdo_test select6-9.7 {
489fe61378aSdrh  execsql {
490fe61378aSdrh    SELECT x FROM (SELECT x FROM t1 LIMIT -1) LIMIT 3;
491fe61378aSdrh  }
492fe61378aSdrh} {1 2 3}
493fe61378aSdrhdo_test select6-9.8 {
494fe61378aSdrh  execsql {
495fe61378aSdrh    SELECT x FROM (SELECT x FROM t1 LIMIT -1);
496fe61378aSdrh  }
497fe61378aSdrh} {1 2 3 4}
498fe61378aSdrhdo_test select6-9.9 {
499fe61378aSdrh  execsql {
500fe61378aSdrh    SELECT x FROM (SELECT x FROM t1 LIMIT -1 OFFSET 1);
501fe61378aSdrh  }
502fe61378aSdrh} {2 3 4}
503e2f02bacSdrhdo_test select6-9.10 {
504e2f02bacSdrh  execsql {
505e2f02bacSdrh    SELECT x, y FROM (SELECT x, (SELECT 10+x) y FROM t1 LIMIT -1 OFFSET 1);
506e2f02bacSdrh  }
507e2f02bacSdrh} {2 12 3 13 4 14}
508e2f02bacSdrhdo_test select6-9.11 {
509e2f02bacSdrh  execsql {
510e2f02bacSdrh    SELECT x, y FROM (SELECT x, (SELECT 10)+x y FROM t1 LIMIT -1 OFFSET 1);
511e2f02bacSdrh  }
512e2f02bacSdrh} {2 12 3 13 4 14}
513fe61378aSdrh
514fe61378aSdrh
51567c70142Sdan#-------------------------------------------------------------------------
51667c70142Sdan# Test that if a UNION ALL sub-query that would otherwise be eligible for
51767c70142Sdan# flattening consists of two or more SELECT statements that do not all
51867c70142Sdan# return the same number of result columns, the error is detected.
51967c70142Sdan#
52067c70142Sdando_execsql_test 10.1 {
52167c70142Sdan  CREATE TABLE t(i,j,k);
52267c70142Sdan  CREATE TABLE j(l,m);
52367c70142Sdan  CREATE TABLE k(o);
52467c70142Sdan}
52567c70142Sdan
52667c70142Sdanset err [list 1 {SELECTs to the left and right of UNION ALL do not have the same number of result columns}]
52767c70142Sdan
52867c70142Sdando_execsql_test 10.2 {
52967c70142Sdan  SELECT * FROM (SELECT * FROM t), j;
53067c70142Sdan}
53167c70142Sdando_catchsql_test 10.3 {
53267c70142Sdan  SELECT * FROM t UNION ALL SELECT * FROM j
53367c70142Sdan} $err
53467c70142Sdando_catchsql_test 10.4 {
53567c70142Sdan  SELECT * FROM (SELECT i FROM t UNION ALL SELECT l, m FROM j)
53667c70142Sdan} $err
53767c70142Sdando_catchsql_test 10.5 {
53867c70142Sdan  SELECT * FROM (SELECT j FROM t UNION ALL SELECT * FROM j)
53967c70142Sdan} $err
54067c70142Sdando_catchsql_test 10.6 {
54167c70142Sdan  SELECT * FROM (SELECT * FROM t UNION ALL SELECT * FROM j)
54267c70142Sdan} $err
54367c70142Sdando_catchsql_test 10.7 {
54467c70142Sdan  SELECT * FROM (
54567c70142Sdan    SELECT * FROM t UNION ALL
54667c70142Sdan    SELECT l,m,l FROM j UNION ALL
54767c70142Sdan    SELECT * FROM k
54867c70142Sdan  )
54967c70142Sdan} $err
55067c70142Sdando_catchsql_test 10.8 {
55167c70142Sdan  SELECT * FROM (
55267c70142Sdan    SELECT * FROM k UNION ALL
55367c70142Sdan    SELECT * FROM t UNION ALL
55467c70142Sdan    SELECT l,m,l FROM j
55567c70142Sdan  )
55667c70142Sdan} $err
55767c70142Sdan
5582c5e9b56Sdrh# 2015-02-09 Ticket [2f7170d73bf9abf80339187aa3677dce3dbcd5ca]
5592c5e9b56Sdrh# "misuse of aggregate" error if aggregate column from FROM
5602c5e9b56Sdrh# subquery is used in correlated subquery
5612c5e9b56Sdrh#
5622c5e9b56Sdrhdo_execsql_test 11.1 {
5632c5e9b56Sdrh  DROP TABLE IF EXISTS t1;
5642c5e9b56Sdrh  CREATE TABLE t1(w INT, x INT);
5652c5e9b56Sdrh  INSERT INTO t1(w,x)
5662c5e9b56Sdrh   VALUES(1,10),(2,20),(3,30),
5672c5e9b56Sdrh         (2,21),(3,31),
5682c5e9b56Sdrh         (3,32);
5692c5e9b56Sdrh  CREATE INDEX t1wx ON t1(w,x);
5702c5e9b56Sdrh
5712c5e9b56Sdrh  DROP TABLE IF EXISTS t2;
5722c5e9b56Sdrh  CREATE TABLE t2(w INT, y VARCHAR(8));
5732c5e9b56Sdrh  INSERT INTO t2(w,y) VALUES(1,'one'),(2,'two'),(3,'three'),(4,'four');
5742c5e9b56Sdrh  CREATE INDEX t2wy ON t2(w,y);
5752c5e9b56Sdrh
5762c5e9b56Sdrh  SELECT cnt, xyz, (SELECT y FROM t2 WHERE w=cnt), '|'
5772c5e9b56Sdrh    FROM (SELECT count(*) AS cnt, w AS xyz FROM t1 GROUP BY 2)
5782c5e9b56Sdrh   ORDER BY cnt, xyz;
5792c5e9b56Sdrh} {1 1 one | 2 2 two | 3 3 three |}
5802c5e9b56Sdrhdo_execsql_test 11.2 {
5812c5e9b56Sdrh  SELECT cnt, xyz, lower((SELECT y FROM t2 WHERE w=cnt)), '|'
5822c5e9b56Sdrh    FROM (SELECT count(*) AS cnt, w AS xyz FROM t1 GROUP BY 2)
5832c5e9b56Sdrh   ORDER BY cnt, xyz;
5842c5e9b56Sdrh} {1 1 one | 2 2 two | 3 3 three |}
5852c5e9b56Sdrhdo_execsql_test 11.3 {
5862c5e9b56Sdrh  SELECT cnt, xyz, '|'
5872c5e9b56Sdrh    FROM (SELECT count(*) AS cnt, w AS xyz FROM t1 GROUP BY 2)
5882c5e9b56Sdrh   WHERE (SELECT y FROM t2 WHERE w=cnt)!='two'
5892c5e9b56Sdrh   ORDER BY cnt, xyz;
5902c5e9b56Sdrh} {1 1 | 3 3 |}
5912c5e9b56Sdrhdo_execsql_test 11.4 {
5922c5e9b56Sdrh  SELECT cnt, xyz, '|'
5932c5e9b56Sdrh    FROM (SELECT count(*) AS cnt, w AS xyz FROM t1 GROUP BY 2)
5942c5e9b56Sdrh   ORDER BY lower((SELECT y FROM t2 WHERE w=cnt));
5952c5e9b56Sdrh} {1 1 | 3 3 | 2 2 |}
5962c5e9b56Sdrhdo_execsql_test 11.5 {
5972c5e9b56Sdrh  SELECT cnt, xyz,
5982c5e9b56Sdrh         CASE WHEN (SELECT y FROM t2 WHERE w=cnt)=='two'
5992c5e9b56Sdrh              THEN 'aaa' ELSE 'bbb'
6002c5e9b56Sdrh          END, '|'
6012c5e9b56Sdrh    FROM (SELECT count(*) AS cnt, w AS xyz FROM t1 GROUP BY 2)
6022c5e9b56Sdrh   ORDER BY +cnt;
6032c5e9b56Sdrh} {1 1 bbb | 2 2 aaa | 3 3 bbb |}
6042c5e9b56Sdrh
6052c5e9b56Sdrhdo_execsql_test 11.100 {
6062c5e9b56Sdrh  DROP TABLE t1;
6072c5e9b56Sdrh  DROP TABLE t2;
6082c5e9b56Sdrh  CREATE TABLE t1(x);
6092c5e9b56Sdrh  CREATE TABLE t2(y, z);
6102c5e9b56Sdrh  SELECT ( SELECT y FROM t2 WHERE z = cnt )
6112c5e9b56Sdrh    FROM ( SELECT count(*) AS cnt FROM t1 );
6122c5e9b56Sdrh} {{}}
6132c5e9b56Sdrh
614*7cd5e856Sdrh# 2019-05-29 ticket https://www.sqlite.org/src/info/c41afac34f15781f
615*7cd5e856Sdrh# A LIMIT clause in a subquery is incorrectly applied to a subquery.
616*7cd5e856Sdrh#
617*7cd5e856Sdrhdo_execsql_test 12.100 {
618*7cd5e856Sdrh  DROP TABLE t1;
619*7cd5e856Sdrh  DROP TABLE t2;
620*7cd5e856Sdrh  CREATE TABLE t1(a);
621*7cd5e856Sdrh  INSERT INTO t1 VALUES(1);
622*7cd5e856Sdrh  INSERT INTO t1 VALUES(2);
623*7cd5e856Sdrh  CREATE TABLE t2(b);
624*7cd5e856Sdrh  INSERT INTO t2 VALUES(3);
625*7cd5e856Sdrh  SELECT * FROM (
626*7cd5e856Sdrh    SELECT * FROM (SELECT * FROM t1 LIMIT 1)
627*7cd5e856Sdrh    UNION ALL
628*7cd5e856Sdrh    SELECT * from t2);
629*7cd5e856Sdrh} {1 3}
630e9ffc168Sdrh
631d820cb1bSdrhfinish_test
632