xref: /sqlite-3.40.0/test/subquery.test (revision 7d44b22d)
1801845fbSdrh# 2005 January 19
2801845fbSdrh#
3801845fbSdrh# The author disclaims copyright to this source code.  In place of
4801845fbSdrh# a legal notice, here is a blessing:
5801845fbSdrh#
6801845fbSdrh#    May you do good and not evil.
7801845fbSdrh#    May you find forgiveness for yourself and forgive others.
8801845fbSdrh#    May you share freely, never taking more than you give.
9801845fbSdrh#
10801845fbSdrh#*************************************************************************
11801845fbSdrh# This file implements regression tests for SQLite library.  The
12801845fbSdrh# focus of this script is testing correlated subqueries
13801845fbSdrh#
14e2f02bacSdrh# $Id: subquery.test,v 1.17 2009/01/09 01:12:28 drh Exp $
15801845fbSdrh#
16801845fbSdrh
17801845fbSdrhset testdir [file dirname $argv0]
18801845fbSdrhsource $testdir/tester.tcl
19801845fbSdrh
20576ec6b3Sdanielk1977ifcapable !subquery {
21576ec6b3Sdanielk1977  finish_test
22576ec6b3Sdanielk1977  return
23576ec6b3Sdanielk1977}
24576ec6b3Sdanielk1977
25801845fbSdrhdo_test subquery-1.1 {
26801845fbSdrh  execsql {
27801845fbSdrh    BEGIN;
28801845fbSdrh    CREATE TABLE t1(a,b);
29801845fbSdrh    INSERT INTO t1 VALUES(1,2);
30801845fbSdrh    INSERT INTO t1 VALUES(3,4);
31801845fbSdrh    INSERT INTO t1 VALUES(5,6);
32801845fbSdrh    INSERT INTO t1 VALUES(7,8);
33801845fbSdrh    CREATE TABLE t2(x,y);
34801845fbSdrh    INSERT INTO t2 VALUES(1,1);
35801845fbSdrh    INSERT INTO t2 VALUES(3,9);
36801845fbSdrh    INSERT INTO t2 VALUES(5,25);
37801845fbSdrh    INSERT INTO t2 VALUES(7,49);
38801845fbSdrh    COMMIT;
39801845fbSdrh  }
40801845fbSdrh  execsql {
41801845fbSdrh    SELECT a, (SELECT y FROM t2 WHERE x=a) FROM t1 WHERE b<8
42801845fbSdrh  }
43801845fbSdrh} {1 1 3 9 5 25}
44801845fbSdrhdo_test subquery-1.2 {
45801845fbSdrh  execsql {
46801845fbSdrh    UPDATE t1 SET b=b+(SELECT y FROM t2 WHERE x=a);
47801845fbSdrh    SELECT * FROM t1;
48801845fbSdrh  }
49801845fbSdrh} {1 3 3 13 5 31 7 57}
50801845fbSdrh
51801845fbSdrhdo_test subquery-1.3 {
52801845fbSdrh  execsql {
53801845fbSdrh    SELECT b FROM t1 WHERE EXISTS(SELECT * FROM t2 WHERE y=a)
54801845fbSdrh  }
55801845fbSdrh} {3}
56801845fbSdrhdo_test subquery-1.4 {
57801845fbSdrh  execsql {
58801845fbSdrh    SELECT b FROM t1 WHERE NOT EXISTS(SELECT * FROM t2 WHERE y=a)
59801845fbSdrh  }
60801845fbSdrh} {13 31 57}
61801845fbSdrh
62b3bce662Sdanielk1977# Simple tests to make sure correlated subqueries in WHERE clauses
63b3bce662Sdanielk1977# are used by the query optimizer correctly.
64b3bce662Sdanielk1977do_test subquery-1.5 {
65b3bce662Sdanielk1977  execsql {
66b3bce662Sdanielk1977    SELECT a, x FROM t1, t2 WHERE t1.a = (SELECT x);
67b3bce662Sdanielk1977  }
68b3bce662Sdanielk1977} {1 1 3 3 5 5 7 7}
69b3bce662Sdanielk1977do_test subquery-1.6 {
70b3bce662Sdanielk1977  execsql {
71b3bce662Sdanielk1977    CREATE INDEX i1 ON t1(a);
72b3bce662Sdanielk1977    SELECT a, x FROM t1, t2 WHERE t1.a = (SELECT x);
73b3bce662Sdanielk1977  }
74b3bce662Sdanielk1977} {1 1 3 3 5 5 7 7}
75b3bce662Sdanielk1977do_test subquery-1.7 {
76b3bce662Sdanielk1977  execsql {
77b3bce662Sdanielk1977    SELECT a, x FROM t2, t1 WHERE t1.a = (SELECT x);
78b3bce662Sdanielk1977  }
79b3bce662Sdanielk1977} {1 1 3 3 5 5 7 7}
80b3bce662Sdanielk1977
81b3bce662Sdanielk1977# Try an aggregate in both the subquery and the parent query.
82142bdf40Sdanielk1977do_test subquery-1.8 {
83b3bce662Sdanielk1977  execsql {
84b3bce662Sdanielk1977    SELECT count(*) FROM t1 WHERE a > (SELECT count(*) FROM t2);
85b3bce662Sdanielk1977  }
86b3bce662Sdanielk1977} {2}
87b3bce662Sdanielk1977
88142bdf40Sdanielk1977# Test a correlated subquery disables the "only open the index" optimization.
89142bdf40Sdanielk1977do_test subquery-1.9.1 {
90142bdf40Sdanielk1977  execsql {
91142bdf40Sdanielk1977    SELECT (y*2)>b FROM t1, t2 WHERE a=x;
92142bdf40Sdanielk1977  }
93142bdf40Sdanielk1977} {0 1 1 1}
94142bdf40Sdanielk1977do_test subquery-1.9.2 {
95142bdf40Sdanielk1977  execsql {
96142bdf40Sdanielk1977    SELECT a FROM t1 WHERE (SELECT (y*2)>b FROM t2 WHERE a=x);
97142bdf40Sdanielk1977  }
98142bdf40Sdanielk1977} {3 5 7}
99142bdf40Sdanielk1977
100a1cb183dSdanielk1977# Test that the flattening optimization works with subquery expressions.
101a1cb183dSdanielk1977do_test subquery-1.10.1 {
102a1cb183dSdanielk1977  execsql {
103a1cb183dSdanielk1977    SELECT (SELECT a), b FROM t1;
104a1cb183dSdanielk1977  }
105a1cb183dSdanielk1977} {1 3 3 13 5 31 7 57}
106a1cb183dSdanielk1977do_test subquery-1.10.2 {
107a1cb183dSdanielk1977  execsql {
108a1cb183dSdanielk1977    SELECT * FROM (SELECT (SELECT a), b FROM t1);
109a1cb183dSdanielk1977  }
110a1cb183dSdanielk1977} {1 3 3 13 5 31 7 57}
111a1cb183dSdanielk1977do_test subquery-1.10.3 {
112a1cb183dSdanielk1977  execsql {
113a1cb183dSdanielk1977    SELECT * FROM (SELECT (SELECT sum(a) FROM t1));
114a1cb183dSdanielk1977  }
1153d1d95e6Sdrh} {16}
116a1cb183dSdanielk1977do_test subquery-1.10.4 {
117a1cb183dSdanielk1977  execsql {
118a1cb183dSdanielk1977    CREATE TABLE t5 (val int, period text PRIMARY KEY);
119a1cb183dSdanielk1977    INSERT INTO t5 VALUES(5, '2001-3');
120a1cb183dSdanielk1977    INSERT INTO t5 VALUES(10, '2001-4');
121a1cb183dSdanielk1977    INSERT INTO t5 VALUES(15, '2002-1');
122a1cb183dSdanielk1977    INSERT INTO t5 VALUES(5, '2002-2');
123a1cb183dSdanielk1977    INSERT INTO t5 VALUES(10, '2002-3');
124a1cb183dSdanielk1977    INSERT INTO t5 VALUES(15, '2002-4');
125a1cb183dSdanielk1977    INSERT INTO t5 VALUES(10, '2003-1');
126a1cb183dSdanielk1977    INSERT INTO t5 VALUES(5, '2003-2');
127a1cb183dSdanielk1977    INSERT INTO t5 VALUES(25, '2003-3');
128a1cb183dSdanielk1977    INSERT INTO t5 VALUES(5, '2003-4');
129a1cb183dSdanielk1977
13093a960a0Sdrh    SELECT period, vsum
131a1cb183dSdanielk1977    FROM (SELECT
132a1cb183dSdanielk1977      a.period,
133a1cb183dSdanielk1977      (select sum(val) from t5 where period between a.period and '2002-4') vsum
134a1cb183dSdanielk1977      FROM t5 a where a.period between '2002-1' and '2002-4')
135a1cb183dSdanielk1977    WHERE vsum < 45 ;
136a1cb183dSdanielk1977  }
1373d1d95e6Sdrh} {2002-2 30 2002-3 25 2002-4 15}
138a1cb183dSdanielk1977do_test subquery-1.10.5 {
139a1cb183dSdanielk1977  execsql {
14093a960a0Sdrh    SELECT period, vsum from
1412b6d46b9Sdanielk1977      (select a.period,
1422b6d46b9Sdanielk1977      (select sum(val) from t5 where period between a.period and '2002-4') vsum
1432b6d46b9Sdanielk1977    FROM t5 a where a.period between '2002-1' and '2002-4')
1442b6d46b9Sdanielk1977    WHERE vsum < 45 ;
1452b6d46b9Sdanielk1977  }
1463d1d95e6Sdrh} {2002-2 30 2002-3 25 2002-4 15}
1472b6d46b9Sdanielk1977do_test subquery-1.10.6 {
1482b6d46b9Sdanielk1977  execsql {
149a1cb183dSdanielk1977    DROP TABLE t5;
150a1cb183dSdanielk1977  }
151a1cb183dSdanielk1977} {}
152a1cb183dSdanielk1977
153a1cb183dSdanielk1977
154b3bce662Sdanielk1977
155b3bce662Sdanielk1977#------------------------------------------------------------------
156b3bce662Sdanielk1977# The following test cases - subquery-2.* - are not logically
157b3bce662Sdanielk1977# organized. They're here largely because they were failing during
158b3bce662Sdanielk1977# one stage of development of sub-queries.
159b3bce662Sdanielk1977#
160b3bce662Sdanielk1977do_test subquery-2.1 {
161b3bce662Sdanielk1977  execsql {
162b3bce662Sdanielk1977    SELECT (SELECT 10);
163b3bce662Sdanielk1977  }
164b3bce662Sdanielk1977} {10}
165b3bce662Sdanielk1977do_test subquery-2.2.1 {
166b3bce662Sdanielk1977  execsql {
167b3bce662Sdanielk1977    CREATE TABLE t3(a PRIMARY KEY, b);
168b3bce662Sdanielk1977    INSERT INTO t3 VALUES(1, 2);
169b3bce662Sdanielk1977    INSERT INTO t3 VALUES(3, 1);
170b3bce662Sdanielk1977  }
171b3bce662Sdanielk1977} {}
172b3bce662Sdanielk1977do_test subquery-2.2.2 {
173b3bce662Sdanielk1977  execsql {
174b3bce662Sdanielk1977    SELECT * FROM t3 WHERE a IN (SELECT b FROM t3);
175b3bce662Sdanielk1977  }
176b3bce662Sdanielk1977} {1 2}
177b3bce662Sdanielk1977do_test subquery-2.2.3 {
178b3bce662Sdanielk1977  execsql {
179b3bce662Sdanielk1977    DROP TABLE t3;
180b3bce662Sdanielk1977  }
181b3bce662Sdanielk1977} {}
182b3bce662Sdanielk1977do_test subquery-2.3.1 {
183b3bce662Sdanielk1977  execsql {
184b3bce662Sdanielk1977    CREATE TABLE t3(a TEXT);
185b3bce662Sdanielk1977    INSERT INTO t3 VALUES('10');
186b3bce662Sdanielk1977  }
187b3bce662Sdanielk1977} {}
188b3bce662Sdanielk1977do_test subquery-2.3.2 {
189b3bce662Sdanielk1977  execsql {
190b3bce662Sdanielk1977    SELECT a IN (10.0, 20) FROM t3;
191b3bce662Sdanielk1977  }
192b3bce662Sdanielk1977} {0}
193b3bce662Sdanielk1977do_test subquery-2.3.3 {
194b3bce662Sdanielk1977  execsql {
195b3bce662Sdanielk1977    DROP TABLE t3;
196b3bce662Sdanielk1977  }
197b3bce662Sdanielk1977} {}
198b3bce662Sdanielk1977do_test subquery-2.4.1 {
199b3bce662Sdanielk1977  execsql {
200b3bce662Sdanielk1977    CREATE TABLE t3(a TEXT);
201b3bce662Sdanielk1977    INSERT INTO t3 VALUES('XX');
202b3bce662Sdanielk1977  }
203b3bce662Sdanielk1977} {}
204b3bce662Sdanielk1977do_test subquery-2.4.2 {
205b3bce662Sdanielk1977  execsql {
206b3bce662Sdanielk1977    SELECT count(*) FROM t3 WHERE a IN (SELECT 'XX')
207b3bce662Sdanielk1977  }
208b3bce662Sdanielk1977} {1}
209b3bce662Sdanielk1977do_test subquery-2.4.3 {
210b3bce662Sdanielk1977  execsql {
211b3bce662Sdanielk1977    DROP TABLE t3;
212b3bce662Sdanielk1977  }
213b3bce662Sdanielk1977} {}
214b3bce662Sdanielk1977do_test subquery-2.5.1 {
215b3bce662Sdanielk1977  execsql {
216b3bce662Sdanielk1977    CREATE TABLE t3(a INTEGER);
217b3bce662Sdanielk1977    INSERT INTO t3 VALUES(10);
218b3bce662Sdanielk1977
219b3bce662Sdanielk1977    CREATE TABLE t4(x TEXT);
220b3bce662Sdanielk1977    INSERT INTO t4 VALUES('10.0');
221b3bce662Sdanielk1977  }
222b3bce662Sdanielk1977} {}
223b3bce662Sdanielk1977do_test subquery-2.5.2 {
2247ec764a2Sdrh  # In the expr "x IN (SELECT a FROM t3)" the RHS of the IN operator
2257ec764a2Sdrh  # has text affinity and the LHS has integer affinity.  The rule is
2267ec764a2Sdrh  # that we try to convert both sides to an integer before doing the
2277ec764a2Sdrh  # comparision.  Hence, the integer value 10 in t3 will compare equal
2287ec764a2Sdrh  # to the string value '10.0' in t4 because the t4 value will be
2297ec764a2Sdrh  # converted into an integer.
230b3bce662Sdanielk1977  execsql {
231b3bce662Sdanielk1977    SELECT * FROM t4 WHERE x IN (SELECT a FROM t3);
232b3bce662Sdanielk1977  }
233b3bce662Sdanielk1977} {10.0}
2347ec764a2Sdrhdo_test subquery-2.5.3.1 {
2357ec764a2Sdrh  # The t4i index cannot be used to resolve the "x IN (...)" constraint
2367ec764a2Sdrh  # because the constraint has integer affinity but t4i has text affinity.
237b3bce662Sdanielk1977  execsql {
238b3bce662Sdanielk1977    CREATE INDEX t4i ON t4(x);
239b3bce662Sdanielk1977    SELECT * FROM t4 WHERE x IN (SELECT a FROM t3);
240b3bce662Sdanielk1977  }
241b3bce662Sdanielk1977} {10.0}
2427ec764a2Sdrhdo_test subquery-2.5.3.2 {
2437ec764a2Sdrh  # Verify that the t4i index was not used in the previous query
2447c171098Sdrh  execsql {
2457c171098Sdrh    EXPLAIN QUERY PLAN
2467c171098Sdrh    SELECT * FROM t4 WHERE x IN (SELECT a FROM t3);
2477c171098Sdrh  }
248165674d8Sdrh} {~/t4i/}
249b3bce662Sdanielk1977do_test subquery-2.5.4 {
250b3bce662Sdanielk1977  execsql {
251b3bce662Sdanielk1977    DROP TABLE t3;
252b3bce662Sdanielk1977    DROP TABLE t4;
253b3bce662Sdanielk1977  }
254b3bce662Sdanielk1977} {}
255b3bce662Sdanielk1977
256b3bce662Sdanielk1977#------------------------------------------------------------------
257b3bce662Sdanielk1977# The following test cases - subquery-3.* - test tickets that
258b3bce662Sdanielk1977# were raised during development of correlated subqueries.
259b3bce662Sdanielk1977#
260b3bce662Sdanielk1977
261b3bce662Sdanielk1977# Ticket 1083
262b3bce662Sdanielk1977ifcapable view {
263b3bce662Sdanielk1977  do_test subquery-3.1 {
264b3bce662Sdanielk1977    catchsql { DROP TABLE t1; }
265b3bce662Sdanielk1977    catchsql { DROP TABLE t2; }
266b3bce662Sdanielk1977    execsql {
267b3bce662Sdanielk1977      CREATE TABLE t1(a,b);
268b3bce662Sdanielk1977      INSERT INTO t1 VALUES(1,2);
269b3bce662Sdanielk1977      CREATE VIEW v1 AS SELECT b FROM t1 WHERE a>0;
270b3bce662Sdanielk1977      CREATE TABLE t2(p,q);
271b3bce662Sdanielk1977      INSERT INTO t2 VALUES(2,9);
272b3bce662Sdanielk1977      SELECT * FROM v1 WHERE EXISTS(SELECT * FROM t2 WHERE p=v1.b);
273b3bce662Sdanielk1977    }
274b3bce662Sdanielk1977  } {2}
275e2f02bacSdrh  do_test subquery-3.1.1 {
276e2f02bacSdrh    execsql {
277e2f02bacSdrh      SELECT * FROM v1 WHERE EXISTS(SELECT 1);
278e2f02bacSdrh    }
279e2f02bacSdrh  } {2}
2803bdca9c9Sdanielk1977} else {
2813bdca9c9Sdanielk1977  catchsql { DROP TABLE t1; }
2823bdca9c9Sdanielk1977  catchsql { DROP TABLE t2; }
2833bdca9c9Sdanielk1977  execsql {
2843bdca9c9Sdanielk1977    CREATE TABLE t1(a,b);
2853bdca9c9Sdanielk1977    INSERT INTO t1 VALUES(1,2);
2863bdca9c9Sdanielk1977    CREATE TABLE t2(p,q);
2873bdca9c9Sdanielk1977    INSERT INTO t2 VALUES(2,9);
2883bdca9c9Sdanielk1977  }
289b3bce662Sdanielk1977}
290b3bce662Sdanielk1977
291b3bce662Sdanielk1977# Ticket 1084
292b3bce662Sdanielk1977do_test subquery-3.2 {
293b3bce662Sdanielk1977  catchsql {
294b3bce662Sdanielk1977    CREATE TABLE t1(a,b);
295b3bce662Sdanielk1977    INSERT INTO t1 VALUES(1,2);
296b3bce662Sdanielk1977  }
297b3bce662Sdanielk1977  execsql {
298b3bce662Sdanielk1977    SELECT (SELECT t1.a) FROM t1;
299b3bce662Sdanielk1977  }
300b3bce662Sdanielk1977} {1}
301b3bce662Sdanielk1977
302a58fdfb1Sdanielk1977# Test Cases subquery-3.3.* test correlated subqueries where the
303a58fdfb1Sdanielk1977# parent query is an aggregate query. Ticket #1105 is an example
304a58fdfb1Sdanielk1977# of such a query.
305a58fdfb1Sdanielk1977#
306a58fdfb1Sdanielk1977do_test subquery-3.3.1 {
307a58fdfb1Sdanielk1977  execsql {
308a58fdfb1Sdanielk1977    SELECT a, (SELECT b) FROM t1 GROUP BY a;
309a58fdfb1Sdanielk1977  }
310a58fdfb1Sdanielk1977} {1 2}
311a58fdfb1Sdanielk1977do_test subquery-3.3.2 {
312a58fdfb1Sdanielk1977  catchsql {DROP TABLE t2}
313a58fdfb1Sdanielk1977  execsql {
314a58fdfb1Sdanielk1977    CREATE TABLE t2(c, d);
315a58fdfb1Sdanielk1977    INSERT INTO t2 VALUES(1, 'one');
316a58fdfb1Sdanielk1977    INSERT INTO t2 VALUES(2, 'two');
317a58fdfb1Sdanielk1977    SELECT a, (SELECT d FROM t2 WHERE a=c) FROM t1 GROUP BY a;
318a58fdfb1Sdanielk1977  }
319a58fdfb1Sdanielk1977} {1 one}
320a58fdfb1Sdanielk1977do_test subquery-3.3.3 {
321a58fdfb1Sdanielk1977  execsql {
322a58fdfb1Sdanielk1977    INSERT INTO t1 VALUES(2, 4);
323a58fdfb1Sdanielk1977    SELECT max(a), (SELECT d FROM t2 WHERE a=c) FROM t1;
324a58fdfb1Sdanielk1977  }
325a58fdfb1Sdanielk1977} {2 two}
32624c8ab80Sdanielk1977do_test subquery-3.3.4 {
327a58fdfb1Sdanielk1977  execsql {
328a58fdfb1Sdanielk1977    SELECT a, (SELECT (SELECT d FROM t2 WHERE a=c)) FROM t1 GROUP BY a;
329a58fdfb1Sdanielk1977  }
330a58fdfb1Sdanielk1977} {1 one 2 two}
33124c8ab80Sdanielk1977do_test subquery-3.3.5 {
33224c8ab80Sdanielk1977  execsql {
33324c8ab80Sdanielk1977    SELECT a, (SELECT count(*) FROM t2 WHERE a=c) FROM t1;
33424c8ab80Sdanielk1977  }
33524c8ab80Sdanielk1977} {1 1 2 1}
336a58fdfb1Sdanielk1977
337374fdce4Sdrh# The following tests check for aggregate subqueries in an aggregate
338374fdce4Sdrh# query.
339374fdce4Sdrh#
340374fdce4Sdrhdo_test subquery-3.4.1 {
341374fdce4Sdrh  execsql {
342374fdce4Sdrh    CREATE TABLE t34(x,y);
343374fdce4Sdrh    INSERT INTO t34 VALUES(106,4), (107,3), (106,5), (107,5);
344374fdce4Sdrh    SELECT a.x, avg(a.y)
345374fdce4Sdrh      FROM t34 AS a
346374fdce4Sdrh     GROUP BY a.x
347374fdce4Sdrh     HAVING NOT EXISTS( SELECT b.x, avg(b.y)
348374fdce4Sdrh                          FROM t34 AS b
349374fdce4Sdrh                         GROUP BY b.x
350374fdce4Sdrh                         HAVING avg(a.y) > avg(b.y));
351374fdce4Sdrh  }
352374fdce4Sdrh} {107 4.0}
353374fdce4Sdrhdo_test subquery-3.4.2 {
354374fdce4Sdrh  execsql {
355374fdce4Sdrh    SELECT a.x, avg(a.y) AS avg1
356374fdce4Sdrh      FROM t34 AS a
357374fdce4Sdrh     GROUP BY a.x
358374fdce4Sdrh     HAVING NOT EXISTS( SELECT b.x, avg(b.y) AS avg2
359374fdce4Sdrh                          FROM t34 AS b
360374fdce4Sdrh                         GROUP BY b.x
361374fdce4Sdrh                         HAVING avg1 > avg2);
362374fdce4Sdrh  }
363374fdce4Sdrh} {107 4.0}
364374fdce4Sdrhdo_test subquery-3.4.3 {
365374fdce4Sdrh  execsql {
366374fdce4Sdrh    SELECT
367374fdce4Sdrh       a.x,
368374fdce4Sdrh       avg(a.y),
369374fdce4Sdrh       NOT EXISTS ( SELECT b.x, avg(b.y)
370374fdce4Sdrh                      FROM t34 AS b
371374fdce4Sdrh                      GROUP BY b.x
372374fdce4Sdrh                     HAVING avg(a.y) > avg(b.y)),
373374fdce4Sdrh       EXISTS ( SELECT c.x, avg(c.y)
374374fdce4Sdrh                  FROM t34 AS c
375374fdce4Sdrh                  GROUP BY c.x
376374fdce4Sdrh                 HAVING avg(a.y) > avg(c.y))
377374fdce4Sdrh      FROM t34 AS a
378374fdce4Sdrh     GROUP BY a.x
379374fdce4Sdrh     ORDER BY a.x;
380374fdce4Sdrh  }
381374fdce4Sdrh} {106 4.5 0 1 107 4.0 1 0}
382374fdce4Sdrh
3833a8c4be7Sdrhdo_test subquery-3.5.1 {
3843a8c4be7Sdrh  execsql {
3853a8c4be7Sdrh    CREATE TABLE t35a(x); INSERT INTO t35a VALUES(1),(2),(3);
3863a8c4be7Sdrh    CREATE TABLE t35b(y); INSERT INTO t35b VALUES(98), (99);
3873a8c4be7Sdrh    SELECT max((SELECT avg(y) FROM t35b)) FROM t35a;
3883a8c4be7Sdrh  }
3893a8c4be7Sdrh} {98.5}
3903a8c4be7Sdrhdo_test subquery-3.5.2 {
3913a8c4be7Sdrh  execsql {
3923a8c4be7Sdrh    SELECT max((SELECT count(y) FROM t35b)) FROM t35a;
3933a8c4be7Sdrh  }
3943a8c4be7Sdrh} {2}
3953a8c4be7Sdrhdo_test subquery-3.5.3 {
3963a8c4be7Sdrh  execsql {
3973a8c4be7Sdrh    SELECT max((SELECT count() FROM t35b)) FROM t35a;
3983a8c4be7Sdrh  }
3993a8c4be7Sdrh} {2}
4003a8c4be7Sdrhdo_test subquery-3.5.4 {
4013a8c4be7Sdrh  catchsql {
4023a8c4be7Sdrh    SELECT max((SELECT count(x) FROM t35b)) FROM t35a;
4033a8c4be7Sdrh  }
4043a8c4be7Sdrh} {1 {misuse of aggregate: count()}}
4053a8c4be7Sdrhdo_test subquery-3.5.5 {
4063a8c4be7Sdrh  catchsql {
4073a8c4be7Sdrh    SELECT max((SELECT count(x) FROM t35b)) FROM t35a;
4083a8c4be7Sdrh  }
4093a8c4be7Sdrh} {1 {misuse of aggregate: count()}}
4103a8c4be7Sdrhdo_test subquery-3.5.6 {
4113a8c4be7Sdrh  catchsql {
4123a8c4be7Sdrh    SELECT max((SELECT a FROM (SELECT count(x) AS a FROM t35b))) FROM t35a;
4133a8c4be7Sdrh  }
4143a8c4be7Sdrh} {1 {misuse of aggregate: count()}}
4153a8c4be7Sdrhdo_test subquery-3.5.7 {
4163a8c4be7Sdrh  execsql {
4173a8c4be7Sdrh    SELECT max((SELECT a FROM (SELECT count(y) AS a FROM t35b))) FROM t35a;
4183a8c4be7Sdrh  }
4193a8c4be7Sdrh} {2}
4203a8c4be7Sdrh
421374fdce4Sdrh
422b3bce662Sdanielk1977#------------------------------------------------------------------
423b3bce662Sdanielk1977# These tests - subquery-4.* - use the TCL statement cache to try
424b3bce662Sdanielk1977# and expose bugs to do with re-using statements that have been
425b3bce662Sdanielk1977# passed to sqlite3_reset().
426b3bce662Sdanielk1977#
42748864df9Smistachkin# One problem was that VDBE memory cells were not being initialized
428b3bce662Sdanielk1977# to NULL on the second and subsequent executions.
429b3bce662Sdanielk1977#
430b3bce662Sdanielk1977do_test subquery-4.1.1 {
431b3bce662Sdanielk1977  execsql {
432b3bce662Sdanielk1977    SELECT (SELECT a FROM t1);
433b3bce662Sdanielk1977  }
434b3bce662Sdanielk1977} {1}
435b3bce662Sdanielk1977do_test subquery-4.2 {
436b3bce662Sdanielk1977  execsql {
437b3bce662Sdanielk1977    DELETE FROM t1;
438b3bce662Sdanielk1977    SELECT (SELECT a FROM t1);
439b3bce662Sdanielk1977  }
440b3bce662Sdanielk1977} {{}}
441b3bce662Sdanielk1977do_test subquery-4.2.1 {
442b3bce662Sdanielk1977  execsql {
443b3bce662Sdanielk1977    CREATE TABLE t3(a PRIMARY KEY);
444b3bce662Sdanielk1977    INSERT INTO t3 VALUES(10);
445b3bce662Sdanielk1977  }
446b3bce662Sdanielk1977  execsql {INSERT INTO t3 VALUES((SELECT max(a) FROM t3)+1)}
447b3bce662Sdanielk1977} {}
448b3bce662Sdanielk1977do_test subquery-4.2.2 {
449b3bce662Sdanielk1977  execsql {INSERT INTO t3 VALUES((SELECT max(a) FROM t3)+1)}
450b3bce662Sdanielk1977} {}
451b3bce662Sdanielk1977
45215ccce1cSdrh#------------------------------------------------------------------
45315ccce1cSdrh# The subquery-5.* tests make sure string literals in double-quotes
45415ccce1cSdrh# are handled efficiently.  Double-quote literals are first checked
45515ccce1cSdrh# to see if they match any column names.  If there is not column name
45615ccce1cSdrh# match then those literals are used a string constants.  When a
45715ccce1cSdrh# double-quoted string appears, we want to make sure that the search
45815ccce1cSdrh# for a matching column name did not cause an otherwise static subquery
45915ccce1cSdrh# to become a dynamic (correlated) subquery.
46015ccce1cSdrh#
46115ccce1cSdrhdo_test subquery-5.1 {
46215ccce1cSdrh  proc callcntproc {n} {
46315ccce1cSdrh    incr ::callcnt
46415ccce1cSdrh    return $n
46515ccce1cSdrh  }
46615ccce1cSdrh  set callcnt 0
46715ccce1cSdrh  db function callcnt callcntproc
46815ccce1cSdrh  execsql {
46915ccce1cSdrh    CREATE TABLE t4(x,y);
47015ccce1cSdrh    INSERT INTO t4 VALUES('one',1);
47115ccce1cSdrh    INSERT INTO t4 VALUES('two',2);
47215ccce1cSdrh    INSERT INTO t4 VALUES('three',3);
47315ccce1cSdrh    INSERT INTO t4 VALUES('four',4);
47415ccce1cSdrh    CREATE TABLE t5(a,b);
47515ccce1cSdrh    INSERT INTO t5 VALUES(1,11);
47615ccce1cSdrh    INSERT INTO t5 VALUES(2,22);
47715ccce1cSdrh    INSERT INTO t5 VALUES(3,33);
47815ccce1cSdrh    INSERT INTO t5 VALUES(4,44);
47915ccce1cSdrh    SELECT b FROM t5 WHERE a IN
480*7d44b22dSdrh       (SELECT callcnt(y)+0 FROM t4 WHERE x='two')
48115ccce1cSdrh  }
48215ccce1cSdrh} {22}
48315ccce1cSdrhdo_test subquery-5.2 {
48415ccce1cSdrh  # This is the key test.  The subquery should have only run once.  If
48515ccce1cSdrh  # The double-quoted identifier "two" were causing the subquery to be
48615ccce1cSdrh  # processed as a correlated subquery, then it would have run 4 times.
48715ccce1cSdrh  set callcnt
48815ccce1cSdrh} {1}
48915ccce1cSdrh
49015ccce1cSdrh
49187abf5c0Sdrh# Ticket #1380.  Make sure correlated subqueries on an IN clause work
49287abf5c0Sdrh# correctly when the left-hand side of the IN operator is constant.
49387abf5c0Sdrh#
49487abf5c0Sdrhdo_test subquery-6.1 {
49587abf5c0Sdrh  set callcnt 0
49687abf5c0Sdrh  execsql {
49787abf5c0Sdrh    SELECT x FROM t4 WHERE 1 IN (SELECT callcnt(count(*)) FROM t5 WHERE a=y)
49887abf5c0Sdrh  }
49987abf5c0Sdrh} {one two three four}
50087abf5c0Sdrhdo_test subquery-6.2 {
50187abf5c0Sdrh  set callcnt
50287abf5c0Sdrh} {4}
50387abf5c0Sdrhdo_test subquery-6.3 {
50487abf5c0Sdrh  set callcnt 0
50587abf5c0Sdrh  execsql {
50687abf5c0Sdrh    SELECT x FROM t4 WHERE 1 IN (SELECT callcnt(count(*)) FROM t5 WHERE a=1)
50787abf5c0Sdrh  }
50887abf5c0Sdrh} {one two three four}
50987abf5c0Sdrhdo_test subquery-6.4 {
51087abf5c0Sdrh  set callcnt
51187abf5c0Sdrh} {1}
51287abf5c0Sdrh
51378d1ef1aSdrhif 0 {   #############  disable until we get #2652 fixed
51478d1ef1aSdrh# Ticket #2652.  Allow aggregate functions of outer queries inside
51578d1ef1aSdrh# a non-aggregate subquery.
51678d1ef1aSdrh#
51778d1ef1aSdrhdo_test subquery-7.1 {
51878d1ef1aSdrh  execsql {
51978d1ef1aSdrh    CREATE TABLE t7(c7);
52078d1ef1aSdrh    INSERT INTO t7 VALUES(1);
52178d1ef1aSdrh    INSERT INTO t7 VALUES(2);
52278d1ef1aSdrh    INSERT INTO t7 VALUES(3);
52378d1ef1aSdrh    CREATE TABLE t8(c8);
52478d1ef1aSdrh    INSERT INTO t8 VALUES(100);
52578d1ef1aSdrh    INSERT INTO t8 VALUES(200);
52678d1ef1aSdrh    INSERT INTO t8 VALUES(300);
52778d1ef1aSdrh    CREATE TABLE t9(c9);
52878d1ef1aSdrh    INSERT INTO t9 VALUES(10000);
52978d1ef1aSdrh    INSERT INTO t9 VALUES(20000);
53078d1ef1aSdrh    INSERT INTO t9 VALUES(30000);
53187abf5c0Sdrh
53278d1ef1aSdrh    SELECT (SELECT c7+c8 FROM t7) FROM t8;
53378d1ef1aSdrh  }
53478d1ef1aSdrh} {101 201 301}
53578d1ef1aSdrhdo_test subquery-7.2 {
53678d1ef1aSdrh  execsql {
53778d1ef1aSdrh    SELECT (SELECT max(c7)+c8 FROM t7) FROM t8;
53878d1ef1aSdrh  }
53978d1ef1aSdrh} {103 203 303}
54078d1ef1aSdrhdo_test subquery-7.3 {
54178d1ef1aSdrh  execsql {
54278d1ef1aSdrh    SELECT (SELECT c7+max(c8) FROM t8) FROM t7
54378d1ef1aSdrh  }
54478d1ef1aSdrh} {301}
54578d1ef1aSdrhdo_test subquery-7.4 {
54678d1ef1aSdrh  execsql {
54778d1ef1aSdrh    SELECT (SELECT max(c7)+max(c8) FROM t8) FROM t7
54878d1ef1aSdrh  }
54978d1ef1aSdrh} {303}
55078d1ef1aSdrhdo_test subquery-7.5 {
55178d1ef1aSdrh  execsql {
55278d1ef1aSdrh    SELECT (SELECT c8 FROM t8 WHERE rowid=max(c7)) FROM t7
55378d1ef1aSdrh  }
55478d1ef1aSdrh} {300}
55578d1ef1aSdrhdo_test subquery-7.6 {
55678d1ef1aSdrh  execsql {
55778d1ef1aSdrh    SELECT (SELECT (SELECT max(c7+c8+c9) FROM t9) FROM t8) FROM t7
55878d1ef1aSdrh  }
55978d1ef1aSdrh} {30101 30102 30103}
56078d1ef1aSdrhdo_test subquery-7.7 {
56178d1ef1aSdrh  execsql {
56278d1ef1aSdrh    SELECT (SELECT (SELECT c7+max(c8+c9) FROM t9) FROM t8) FROM t7
56378d1ef1aSdrh  }
56478d1ef1aSdrh} {30101 30102 30103}
56578d1ef1aSdrhdo_test subquery-7.8 {
56678d1ef1aSdrh  execsql {
56778d1ef1aSdrh    SELECT (SELECT (SELECT max(c7)+c8+c9 FROM t9) FROM t8) FROM t7
56878d1ef1aSdrh  }
56978d1ef1aSdrh} {10103}
57078d1ef1aSdrhdo_test subquery-7.9 {
57178d1ef1aSdrh  execsql {
57278d1ef1aSdrh    SELECT (SELECT (SELECT c7+max(c8)+c9 FROM t9) FROM t8) FROM t7
57378d1ef1aSdrh  }
57478d1ef1aSdrh} {10301 10302 10303}
57578d1ef1aSdrhdo_test subquery-7.10 {
57678d1ef1aSdrh  execsql {
57778d1ef1aSdrh    SELECT (SELECT (SELECT c7+c8+max(c9) FROM t9) FROM t8) FROM t7
57878d1ef1aSdrh  }
57978d1ef1aSdrh} {30101 30102 30103}
58078d1ef1aSdrhdo_test subquery-7.11 {
58178d1ef1aSdrh  execsql {
58278d1ef1aSdrh    SELECT (SELECT (SELECT max(c7)+max(c8)+max(c9) FROM t9) FROM t8) FROM t7
58378d1ef1aSdrh  }
58478d1ef1aSdrh} {30303}
58578d1ef1aSdrh}  ;############# Disabled
586801845fbSdrh
587dfb5e1cbSdrh# 2015-04-21.
588dfb5e1cbSdrh# Verify that a memory leak in the table column type and collation analysis
589dfb5e1cbSdrh# is plugged.
590dfb5e1cbSdrh#
591dfb5e1cbSdrhdo_execsql_test subquery-8.1 {
592dfb5e1cbSdrh  CREATE TABLE t8(a TEXT, b INT);
593dfb5e1cbSdrh  SELECT (SELECT 0 FROM (SELECT * FROM t1)) AS x WHERE x;
594dfb5e1cbSdrh  SELECT (SELECT 0 FROM (SELECT * FROM (SELECT 0))) AS x WHERE x;
595dfb5e1cbSdrh} {}
596dfb5e1cbSdrh
5978efc6a8cSdrh# 2022-01-12 https://sqlite.org/forum/forumpost/0ec80f12d02acb3f
5988efc6a8cSdrh#
5998efc6a8cSdrhreset_db
6008efc6a8cSdrhdo_execsql_test subquery-9.1 {
6018efc6a8cSdrh  CREATE TABLE t1(x);
6028efc6a8cSdrh  INSERT INTO t1 VALUES(1),(1),(1);
6038efc6a8cSdrh  SELECT (SELECT DISTINCT x FROM t1 ORDER BY +x LIMIT 1 OFFSET 100) FROM t1;
6048efc6a8cSdrh} {{} {} {}}
6058efc6a8cSdrhdo_execsql_test subquery-9.2 {
6068efc6a8cSdrh  SELECT (SELECT DISTINCT x FROM t1 ORDER BY +x LIMIT 1 OFFSET 0) FROM t1;
6078efc6a8cSdrh} {1 1 1}
6088efc6a8cSdrhdo_execsql_test subquery-9.3 {
6098efc6a8cSdrh  INSERT INTO t1 VALUES(2);
6108efc6a8cSdrh  SELECT (SELECT DISTINCT x FROM t1 ORDER BY +x LIMIT 1 OFFSET 1) FROM t1;
6118efc6a8cSdrh} {2 2 2 2}
6128efc6a8cSdrhdo_execsql_test subquery-9.4 {
6138efc6a8cSdrh  SELECT (SELECT DISTINCT x FROM t1 ORDER BY +x LIMIT 1 OFFSET 2) FROM t1;
6148efc6a8cSdrh} {{} {} {} {}}
6158efc6a8cSdrh
616801845fbSdrhfinish_test
617