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.
13 # This file implements tests for processing aggregate queries with
14 # subqueries in which the subqueries hold the aggregate functions
15 # or in which the subqueries are themselves aggregate queries
18 set testdir [file dirname $argv0]
19 source $testdir/tester.tcl
20 set testprefix aggnested
22 do_test aggnested-1.1 {
24 CREATE TABLE t1(a1 INTEGER);
25 INSERT INTO t1 VALUES(1), (2), (3);
26 CREATE TABLE t2(b1 INTEGER);
27 INSERT INTO t2 VALUES(4), (5);
28 SELECT (SELECT string_agg(a1,'x') FROM t2) FROM t1;
31 do_test aggnested-1.2 {
34 (SELECT string_agg(a1,'x') || '-' || string_agg(b1,'y') FROM t2)
38 do_test aggnested-1.3 {
40 SELECT (SELECT string_agg(b1,a1) FROM t2) FROM t1;
43 do_test aggnested-1.4 {
45 SELECT (SELECT group_concat(a1,b1) FROM t2) FROM t1;
50 # This test case is a copy of the one in
51 # http://www.mail-archive.com/sqlite-users@sqlite.org/msg70787.html
53 do_test aggnested-2.0 {
56 CREATE TABLE t1 (A1 INTEGER NOT NULL,A2 INTEGER NOT NULL,A3 INTEGER NOT
57 NULL,A4 INTEGER NOT NULL,PRIMARY KEY(A1));
58 REPLACE INTO t1 VALUES(1,11,111,1111);
59 REPLACE INTO t1 VALUES(2,22,222,2222);
60 REPLACE INTO t1 VALUES(3,33,333,3333);
61 CREATE TABLE t2 (B1 INTEGER NOT NULL,B2 INTEGER NOT NULL,B3 INTEGER NOT
62 NULL,B4 INTEGER NOT NULL,PRIMARY KEY(B1));
63 REPLACE INTO t2 VALUES(1,88,888,8888);
64 REPLACE INTO t2 VALUES(2,99,999,9999);
65 SELECT (SELECT GROUP_CONCAT(CASE WHEN a1=1 THEN'A' ELSE 'B' END) FROM t2),
69 } {A,B,B 1 11 111 1111}
72 ##################### Test cases for ticket [bfbf38e5e9956ac69f] ############
74 # This first test case is the original problem report:
75 do_test aggnested-3.0 {
78 aaa_id INTEGER PRIMARY KEY AUTOINCREMENT
81 rrr_id INTEGER PRIMARY KEY AUTOINCREMENT,
82 rrr_date INTEGER NOT NULL,
86 ttt_id INTEGER PRIMARY KEY AUTOINCREMENT,
87 target_aaa INTEGER NOT NULL,
88 source_aaa INTEGER NOT NULL
90 insert into AAA (aaa_id) values (2);
91 insert into TTT (ttt_id, target_aaa, source_aaa)
93 insert into TTT (ttt_id, target_aaa, source_aaa)
95 insert into RRR (rrr_id, rrr_date, rrr_aaa)
97 insert into RRR (rrr_id, rrr_date, rrr_aaa)
100 (SELECT sum(CASE WHEN (t.source_aaa == i.aaa_id) THEN 1 ELSE 0 END)
104 (SELECT curr.rrr_aaa as aaa_id
106 -- you also can comment out the next line
107 -- it causes segfault to happen after one row is outputted
108 INNER JOIN AAA a ON (curr.rrr_aaa = aaa_id)
109 LEFT JOIN RRR r ON (r.rrr_id <> 0 AND r.rrr_date < curr.rrr_date)
111 HAVING r.rrr_date IS NULL
116 # Further variants of the test case, as found in the ticket
118 do_test aggnested-3.1 {
120 DROP TABLE IF EXISTS t1;
121 DROP TABLE IF EXISTS t2;
123 id1 INTEGER PRIMARY KEY AUTOINCREMENT,
126 INSERT INTO t1 VALUES(4469,2),(4476,1);
128 id2 INTEGER PRIMARY KEY AUTOINCREMENT,
131 INSERT INTO t2 VALUES(0,1),(2,2);
133 (SELECT sum(value2==xyz) FROM t2)
135 (SELECT curr.value1 as xyz
136 FROM t1 AS curr LEFT JOIN t1 AS other
140 do_test aggnested-3.1-rj {
143 (SELECT sum(value2==xyz) FROM t2)
145 (SELECT curr.value1 as xyz
146 FROM t1 AS other RIGHT JOIN t1 AS curr
151 do_test aggnested-3.2 {
153 DROP TABLE IF EXISTS t1;
154 DROP TABLE IF EXISTS t2;
160 INSERT INTO t1 VALUES(4469,2,98),(4469,1,99),(4469,3,97);
164 INSERT INTO t2 VALUES(1);
166 (SELECT sum(value2==xyz) FROM t2)
168 (SELECT value1 as xyz, max(x1) AS pqr
172 (SELECT sum(value2<>xyz) FROM t2)
174 (SELECT value1 as xyz, max(x1) AS pqr
179 do_test aggnested-3.3 {
181 DROP TABLE IF EXISTS t1;
182 DROP TABLE IF EXISTS t2;
183 CREATE TABLE t1(id1, value1);
184 INSERT INTO t1 VALUES(4469,2),(4469,1);
185 CREATE TABLE t2 (value2);
186 INSERT INTO t2 VALUES(1);
187 SELECT (SELECT sum(value2=value1) FROM t2), max(value1)
193 # A batch of queries all doing approximately the same operation involving
194 # two nested aggregate queries.
196 do_test aggnested-3.11 {
198 DROP TABLE IF EXISTS t1;
199 DROP TABLE IF EXISTS t2;
200 CREATE TABLE t1(id1, value1);
201 INSERT INTO t1 VALUES(4469,12),(4469,11),(4470,34);
202 CREATE INDEX t1id1 ON t1(id1);
203 CREATE TABLE t2 (value2);
204 INSERT INTO t2 VALUES(12),(34),(34);
205 INSERT INTO t2 SELECT value2 FROM t2;
207 SELECT max(value1), (SELECT count(*) FROM t2 WHERE value2=max(value1))
212 do_test aggnested-3.12 {
214 SELECT max(value1), (SELECT count(*) FROM t2 WHERE value2=value1)
219 do_test aggnested-3.13 {
221 SELECT value1, (SELECT sum(value2=value1) FROM t2)
225 do_test aggnested-3.14 {
227 SELECT value1, (SELECT sum(value2=value1) FROM t2)
229 WHERE value1 IN (SELECT max(value1) FROM t1 GROUP BY id1);
232 do_test aggnested-3.15 {
233 # FIXME: If case 3.16 works, then this case really ought to work too...
235 SELECT max(value1), (SELECT sum(value2=max(value1)) FROM t2)
239 } {1 {misuse of aggregate function max()}}
240 do_test aggnested-3.16 {
242 SELECT max(value1), (SELECT sum(value2=value1) FROM t2)
249 # Problem found by dbsqlfuzz
251 do_execsql_test aggnested-4.1 {
252 DROP TABLE IF EXISTS aa;
253 DROP TABLE IF EXISTS bb;
254 CREATE TABLE aa(x INT); INSERT INTO aa(x) VALUES(123);
255 CREATE TABLE bb(y INT); INSERT INTO bb(y) VALUES(456);
256 SELECT (SELECT sum(x+(SELECT y)) FROM bb) FROM aa;
258 do_execsql_test aggnested-4.2 {
259 SELECT (SELECT sum(x+y) FROM bb) FROM aa;
261 do_execsql_test aggnested-4.3 {
262 DROP TABLE IF EXISTS tx;
263 DROP TABLE IF EXISTS ty;
264 CREATE TABLE tx(x INT);
265 INSERT INTO tx VALUES(1),(2),(3),(4),(5);
266 CREATE TABLE ty(y INT);
267 INSERT INTO ty VALUES(91),(92),(93);
268 SELECT min((SELECT count(y) FROM ty)) FROM tx;
270 do_execsql_test aggnested-4.4 {
271 SELECT max((SELECT a FROM (SELECT count(*) AS a FROM ty) AS s)) FROM tx;
274 #--------------------------------------------------------------------------
277 do_execsql_test 5.0 {
278 CREATE TABLE x1(a, b);
279 INSERT INTO x1 VALUES(1, 2);
281 INSERT INTO x2 VALUES(NULL), (NULL), (NULL);
284 # At one point, aggregate "total()" in the query below was being processed
285 # as part of the outer SELECT, not as part of the sub-select with no FROM
287 do_execsql_test 5.1 {
288 SELECT ( SELECT total( (SELECT b FROM x1) ) ) FROM x2;
291 do_execsql_test 5.2 {
292 SELECT ( SELECT total( (SELECT 2 FROM x1) ) ) FROM x2;
295 do_execsql_test 5.3 {
300 do_execsql_test 5.4 {
302 SELECT max(b) LIMIT (
303 SELECT total( (SELECT a FROM t1) )
309 do_execsql_test 5.5 {
312 SELECT(SELECT(SELECT string_agg(b, b)
313 LIMIT(SELECT 0.100000 *
314 AVG(DISTINCT(SELECT 0 FROM a ORDER BY b, b, b))))
316 b, b) FROM a EXCEPT SELECT b FROM a ORDER BY b,
320 #-------------------------------------------------------------------------
321 # dbsqlfuzz a779227f721a834df95f4f42d0c31550a1f8b8a2
324 do_execsql_test 6.0 {
328 INSERT INTO t1 VALUES('x');
329 INSERT INTO t2 VALUES(1);
332 do_execsql_test 6.1.1 {
334 SELECT t2.b FROM (SELECT t2.b AS c FROM t1) GROUP BY 1 HAVING t2.b
336 FROM t2 GROUP BY 'constant_string';
338 do_execsql_test 6.1.2 {
340 SELECT c FROM (SELECT t2.b AS c FROM t1) GROUP BY c HAVING t2.b
342 FROM t2 GROUP BY 'constant_string';
345 do_execsql_test 6.2.0 {
348 do_execsql_test 6.2.1 {
350 SELECT t2.b FROM (SELECT t2.b AS c FROM t1) GROUP BY 1 HAVING t2.b
352 FROM t2 GROUP BY 'constant_string';
354 do_execsql_test 6.2.2 {
356 SELECT c FROM (SELECT t2.b AS c FROM t1) GROUP BY c HAVING t2.b
358 FROM t2 GROUP BY 'constant_string';
361 #-------------------------------------------------------------------------
364 do_execsql_test 7.0 {
365 CREATE TABLE invoice (
366 id INTEGER PRIMARY KEY AUTOINCREMENT NOT NULL,
367 amount DOUBLE PRECISION DEFAULT NULL,
368 name VARCHAR(100) DEFAULT NULL
371 INSERT INTO invoice (amount, name) VALUES
372 (4.0, 'Michael'), (15.0, 'Bara'), (4.0, 'Michael'), (6.0, 'John');
375 do_execsql_test 7.1 {
376 SELECT sum(amount), name
379 having (select v > 6 from (select sum(amount) v) t)
385 do_execsql_test 7.2 {
386 SELECT (select 1 from (select sum(amount))) FROM invoice
389 do_execsql_test 8.0 {
390 CREATE TABLE t1(x INT);
391 INSERT INTO t1 VALUES(100);
392 INSERT INTO t1 VALUES(20);
393 INSERT INTO t1 VALUES(3);
394 SELECT (SELECT y FROM (SELECT sum(x) AS y) AS t2 ) FROM t1;
397 do_execsql_test 8.1 {
400 SELECT z AS y FROM (SELECT sum(x) AS z) AS t2
405 do_execsql_test 8.2 {
409 SELECT z AS y FROM (SELECT sum(x) AS z) AS t2
415 #-------------------------------------------------------------------------
416 # dbsqlfuzz 04408efc51ae46897c4c122b407412045ed221b4
420 do_execsql_test 9.1 {
421 WITH out(i, j, k) AS (
422 VALUES(1234, 5678, 9012)
426 SELECT min(abc) = ( SELECT ( SELECT 1234 fROM (SELECT abc) ) )
428 SELECT sum( out.i ) + ( SELECT sum( out.i ) ) AS abc FROM (SELECT out.j)
434 do_execsql_test 9.2 {
437 INSERT INTO t1 VALUES(1), (2), (3);
438 INSERT INTO t2 VALUES(4), (5), (6);
441 SELECT min(y) + (SELECT x) FROM (
442 SELECT sum(a) AS x, b AS y FROM t2
448 do_execsql_test 9.3 {
450 SELECT min(y) + (SELECT (SELECT x)) FROM (
451 SELECT sum(a) AS x, b AS y FROM t2
457 do_execsql_test 9.4 {
459 SELECT (SELECT x) FROM (
460 SELECT sum(a) AS x, b AS y FROM t2
466 do_execsql_test 9.5 {
468 SELECT (SELECT (SELECT x)) FROM (
469 SELECT sum(a) AS x, b AS y FROM t2
476 # New test case for check-in [4470f657d2069972] from 2023-11-02
477 # https://bugs.chromium.org/p/chromium/issues/detail?id=1511689
479 do_execsql_test 10.1 {
480 DROP TABLE IF EXISTS t0;
481 DROP TABLE IF EXISTS t1;
482 CREATE TABLE t0(c1, c2); INSERT INTO t0 VALUES(1,2);
483 CREATE TABLE t1(c3, c4); INSERT INTO t1 VALUES(3,4);
484 SELECT * FROM t0 WHERE EXISTS (SELECT 1 FROM t1 GROUP BY c3 HAVING ( SELECT count(*) FROM (SELECT 1 UNION ALL SELECT sum(DISTINCT c1) ) ) ) BETWEEN 1 AND 1;