xref: /sqlite-3.40.0/test/aggnested.test (revision ec27077c)
180f6bfc0Sdrh# 2012-08-23
2030796dfSdrh#
3030796dfSdrh# The author disclaims copyright to this source code.  In place of
4030796dfSdrh# a legal notice, here is a blessing:
5030796dfSdrh#
6030796dfSdrh#    May you do good and not evil.
7030796dfSdrh#    May you find forgiveness for yourself and forgive others.
8030796dfSdrh#    May you share freely, never taking more than you give.
9030796dfSdrh#
10030796dfSdrh#***********************************************************************
11030796dfSdrh# This file implements regression tests for SQLite library.
12030796dfSdrh#
13030796dfSdrh# This file implements tests for processing aggregate queries with
14030796dfSdrh# subqueries in which the subqueries hold the aggregate functions
15030796dfSdrh# or in which the subqueries are themselves aggregate queries
16030796dfSdrh#
17030796dfSdrh
18030796dfSdrhset testdir [file dirname $argv0]
19030796dfSdrhsource $testdir/tester.tcl
20ed41a96bSdanset testprefix aggnested
21030796dfSdrh
22030796dfSdrhdo_test aggnested-1.1 {
23030796dfSdrh  db eval {
24030796dfSdrh    CREATE TABLE t1(a1 INTEGER);
25030796dfSdrh    INSERT INTO t1 VALUES(1), (2), (3);
26030796dfSdrh    CREATE TABLE t2(b1 INTEGER);
27030796dfSdrh    INSERT INTO t2 VALUES(4), (5);
28030796dfSdrh    SELECT (SELECT group_concat(a1,'x') FROM t2) FROM t1;
29030796dfSdrh  }
30030796dfSdrh} {1x2x3}
31030796dfSdrhdo_test aggnested-1.2 {
32030796dfSdrh  db eval {
33030796dfSdrh    SELECT
34030796dfSdrh     (SELECT group_concat(a1,'x') || '-' || group_concat(b1,'y') FROM t2)
35030796dfSdrh    FROM t1;
36030796dfSdrh  }
37030796dfSdrh} {1x2x3-4y5}
38ed551b95Sdrhdo_test aggnested-1.3 {
39ed551b95Sdrh  db eval {
40ed551b95Sdrh    SELECT (SELECT group_concat(b1,a1) FROM t2) FROM t1;
41ed551b95Sdrh  }
42ed551b95Sdrh} {415 425 435}
43ed551b95Sdrhdo_test aggnested-1.4 {
44ed551b95Sdrh  db eval {
45ed551b95Sdrh    SELECT (SELECT group_concat(a1,b1) FROM t2) FROM t1;
46ed551b95Sdrh  }
47ed551b95Sdrh} {151 252 353}
48ed551b95Sdrh
49ed551b95Sdrh
50ed551b95Sdrh# This test case is a copy of the one in
51ed551b95Sdrh# http://www.mail-archive.com/[email protected]/msg70787.html
52ed551b95Sdrh#
53ed551b95Sdrhdo_test aggnested-2.0 {
54ed551b95Sdrh  sqlite3 db2 :memory:
55ed551b95Sdrh  db2 eval {
56ed551b95Sdrh    CREATE TABLE t1 (A1 INTEGER NOT NULL,A2 INTEGER NOT NULL,A3 INTEGER NOT
57ed551b95Sdrh    NULL,A4 INTEGER NOT NULL,PRIMARY KEY(A1));
58ed551b95Sdrh    REPLACE INTO t1 VALUES(1,11,111,1111);
59ed551b95Sdrh    REPLACE INTO t1 VALUES(2,22,222,2222);
60ed551b95Sdrh    REPLACE INTO t1 VALUES(3,33,333,3333);
61ed551b95Sdrh    CREATE TABLE t2 (B1 INTEGER NOT NULL,B2 INTEGER NOT NULL,B3 INTEGER NOT
62ed551b95Sdrh    NULL,B4 INTEGER NOT NULL,PRIMARY KEY(B1));
63ed551b95Sdrh    REPLACE INTO t2 VALUES(1,88,888,8888);
64ed551b95Sdrh    REPLACE INTO t2 VALUES(2,99,999,9999);
65ed551b95Sdrh    SELECT (SELECT GROUP_CONCAT(CASE WHEN a1=1 THEN'A' ELSE 'B' END) FROM t2),
66ed551b95Sdrh            t1.*
67ed551b95Sdrh    FROM t1;
68ed551b95Sdrh  }
69280c894bSdan} {A,B,B 1 11 111 1111}
70ed551b95Sdrhdb2 close
71030796dfSdrh
72e0b2d5daSdrh##################### Test cases for ticket [bfbf38e5e9956ac69f] ############
73e0b2d5daSdrh#
74e0b2d5daSdrh# This first test case is the original problem report:
75e0b2d5daSdrhdo_test aggnested-3.0 {
76e0b2d5daSdrh  db eval {
77e0b2d5daSdrh    CREATE TABLE AAA (
78e0b2d5daSdrh      aaa_id       INTEGER PRIMARY KEY AUTOINCREMENT
79e0b2d5daSdrh    );
80e0b2d5daSdrh    CREATE TABLE RRR (
81e0b2d5daSdrh      rrr_id      INTEGER     PRIMARY KEY AUTOINCREMENT,
82e0b2d5daSdrh      rrr_date    INTEGER     NOT NULL,
83e0b2d5daSdrh      rrr_aaa     INTEGER
84e0b2d5daSdrh    );
85e0b2d5daSdrh    CREATE TABLE TTT (
86e0b2d5daSdrh      ttt_id      INTEGER PRIMARY KEY AUTOINCREMENT,
87e0b2d5daSdrh      target_aaa  INTEGER NOT NULL,
88e0b2d5daSdrh      source_aaa  INTEGER NOT NULL
89e0b2d5daSdrh    );
90e0b2d5daSdrh    insert into AAA (aaa_id) values (2);
91e0b2d5daSdrh    insert into TTT (ttt_id, target_aaa, source_aaa)
92e0b2d5daSdrh    values (4469, 2, 2);
93e0b2d5daSdrh    insert into TTT (ttt_id, target_aaa, source_aaa)
94e0b2d5daSdrh    values (4476, 2, 1);
95e0b2d5daSdrh    insert into RRR (rrr_id, rrr_date, rrr_aaa)
96e0b2d5daSdrh    values (0, 0, NULL);
97e0b2d5daSdrh    insert into RRR (rrr_id, rrr_date, rrr_aaa)
98e0b2d5daSdrh    values (2, 4312, 2);
99e0b2d5daSdrh    SELECT i.aaa_id,
100e0b2d5daSdrh      (SELECT sum(CASE WHEN (t.source_aaa == i.aaa_id) THEN 1 ELSE 0 END)
101e0b2d5daSdrh         FROM TTT t
102e0b2d5daSdrh      ) AS segfault
103e0b2d5daSdrh    FROM
104e0b2d5daSdrh     (SELECT curr.rrr_aaa as aaa_id
105e0b2d5daSdrh        FROM RRR curr
106e0b2d5daSdrh          -- you also can comment out the next line
107e0b2d5daSdrh          -- it causes segfault to happen after one row is outputted
108e0b2d5daSdrh          INNER JOIN AAA a ON (curr.rrr_aaa = aaa_id)
109e0b2d5daSdrh          LEFT JOIN RRR r ON (r.rrr_id <> 0 AND r.rrr_date < curr.rrr_date)
110e0b2d5daSdrh       GROUP BY curr.rrr_id
111e0b2d5daSdrh      HAVING r.rrr_date IS NULL
112e0b2d5daSdrh    ) i;
113e0b2d5daSdrh  }
114e0b2d5daSdrh} {2 1}
115e0b2d5daSdrh
116e0b2d5daSdrh# Further variants of the test case, as found in the ticket
117e0b2d5daSdrh#
118e0b2d5daSdrhdo_test aggnested-3.1 {
119e0b2d5daSdrh  db eval {
120e0b2d5daSdrh    DROP TABLE IF EXISTS t1;
121e0b2d5daSdrh    DROP TABLE IF EXISTS t2;
122e0b2d5daSdrh    CREATE TABLE t1 (
123e0b2d5daSdrh      id1 INTEGER PRIMARY KEY AUTOINCREMENT,
124e0b2d5daSdrh      value1 INTEGER
125e0b2d5daSdrh    );
126e0b2d5daSdrh    INSERT INTO t1 VALUES(4469,2),(4476,1);
127e0b2d5daSdrh    CREATE TABLE t2 (
128e0b2d5daSdrh      id2 INTEGER PRIMARY KEY AUTOINCREMENT,
129e0b2d5daSdrh      value2 INTEGER
130e0b2d5daSdrh    );
131e0b2d5daSdrh    INSERT INTO t2 VALUES(0,1),(2,2);
132e0b2d5daSdrh    SELECT
133e0b2d5daSdrh     (SELECT sum(value2==xyz) FROM t2)
134e0b2d5daSdrh    FROM
135e0b2d5daSdrh     (SELECT curr.value1 as xyz
136e0b2d5daSdrh        FROM t1 AS curr LEFT JOIN t1 AS other
137e0b2d5daSdrh       GROUP BY curr.id1);
138e0b2d5daSdrh  }
139e0b2d5daSdrh} {1 1}
140*ec27077cSdrhdo_test aggnested-3.1-rj {
141*ec27077cSdrh  db eval {
142*ec27077cSdrh    SELECT
143*ec27077cSdrh     (SELECT sum(value2==xyz) FROM t2)
144*ec27077cSdrh    FROM
145*ec27077cSdrh     (SELECT curr.value1 as xyz
146*ec27077cSdrh        FROM t1 AS other RIGHT JOIN t1 AS curr
147*ec27077cSdrh       GROUP BY curr.id1);
148*ec27077cSdrh  }
149*ec27077cSdrh} {1 1}
150*ec27077cSdrh
151e0b2d5daSdrhdo_test aggnested-3.2 {
152e0b2d5daSdrh  db eval {
153e0b2d5daSdrh    DROP TABLE IF EXISTS t1;
154e0b2d5daSdrh    DROP TABLE IF EXISTS t2;
155e0b2d5daSdrh    CREATE TABLE t1 (
156e0b2d5daSdrh      id1 INTEGER,
157e0b2d5daSdrh      value1 INTEGER,
158e0b2d5daSdrh      x1 INTEGER
159e0b2d5daSdrh    );
160e0b2d5daSdrh    INSERT INTO t1 VALUES(4469,2,98),(4469,1,99),(4469,3,97);
161e0b2d5daSdrh    CREATE TABLE t2 (
162e0b2d5daSdrh      value2 INTEGER
163e0b2d5daSdrh    );
164e0b2d5daSdrh    INSERT INTO t2 VALUES(1);
165e0b2d5daSdrh    SELECT
166e0b2d5daSdrh     (SELECT sum(value2==xyz) FROM t2)
167e0b2d5daSdrh    FROM
168e0b2d5daSdrh     (SELECT value1 as xyz, max(x1) AS pqr
169e0b2d5daSdrh        FROM t1
170e0b2d5daSdrh       GROUP BY id1);
1719588ad95Sdrh    SELECT
1729588ad95Sdrh     (SELECT sum(value2<>xyz) FROM t2)
1739588ad95Sdrh    FROM
1749588ad95Sdrh     (SELECT value1 as xyz, max(x1) AS pqr
1759588ad95Sdrh        FROM t1
1769588ad95Sdrh       GROUP BY id1);
177e0b2d5daSdrh  }
1789588ad95Sdrh} {1 0}
179e0b2d5daSdrhdo_test aggnested-3.3 {
180e0b2d5daSdrh  db eval {
181e0b2d5daSdrh    DROP TABLE IF EXISTS t1;
182e0b2d5daSdrh    DROP TABLE IF EXISTS t2;
183e0b2d5daSdrh    CREATE TABLE t1(id1, value1);
184e0b2d5daSdrh    INSERT INTO t1 VALUES(4469,2),(4469,1);
185e0b2d5daSdrh    CREATE TABLE t2 (value2);
186e0b2d5daSdrh    INSERT INTO t2 VALUES(1);
187e0b2d5daSdrh    SELECT (SELECT sum(value2=value1) FROM t2), max(value1)
188e0b2d5daSdrh      FROM t1
189e0b2d5daSdrh     GROUP BY id1;
190e0b2d5daSdrh  }
191e0b2d5daSdrh} {0 2}
192e0b2d5daSdrh
193e0b2d5daSdrh# A batch of queries all doing approximately the same operation involving
194e0b2d5daSdrh# two nested aggregate queries.
195e0b2d5daSdrh#
196e0b2d5daSdrhdo_test aggnested-3.11 {
197e0b2d5daSdrh  db eval {
198e0b2d5daSdrh    DROP TABLE IF EXISTS t1;
199e0b2d5daSdrh    DROP TABLE IF EXISTS t2;
200e0b2d5daSdrh    CREATE TABLE t1(id1, value1);
201e0b2d5daSdrh    INSERT INTO t1 VALUES(4469,12),(4469,11),(4470,34);
202e0b2d5daSdrh    CREATE INDEX t1id1 ON t1(id1);
203e0b2d5daSdrh    CREATE TABLE t2 (value2);
204e0b2d5daSdrh    INSERT INTO t2 VALUES(12),(34),(34);
205e0b2d5daSdrh    INSERT INTO t2 SELECT value2 FROM t2;
206e0b2d5daSdrh
207e0b2d5daSdrh    SELECT max(value1), (SELECT count(*) FROM t2 WHERE value2=max(value1))
208e0b2d5daSdrh      FROM t1
209e0b2d5daSdrh     GROUP BY id1;
210e0b2d5daSdrh  }
211e0b2d5daSdrh} {12 2 34 4}
212e0b2d5daSdrhdo_test aggnested-3.12 {
213e0b2d5daSdrh  db eval {
214e0b2d5daSdrh    SELECT max(value1), (SELECT count(*) FROM t2 WHERE value2=value1)
215e0b2d5daSdrh      FROM t1
216e0b2d5daSdrh     GROUP BY id1;
217e0b2d5daSdrh  }
218e0b2d5daSdrh} {12 2 34 4}
219e0b2d5daSdrhdo_test aggnested-3.13 {
220e0b2d5daSdrh  db eval {
221e0b2d5daSdrh    SELECT value1, (SELECT sum(value2=value1) FROM t2)
222e0b2d5daSdrh      FROM t1;
223e0b2d5daSdrh  }
224e0b2d5daSdrh} {12 2 11 0 34 4}
225e0b2d5daSdrhdo_test aggnested-3.14 {
226e0b2d5daSdrh  db eval {
227e0b2d5daSdrh    SELECT value1, (SELECT sum(value2=value1) FROM t2)
228e0b2d5daSdrh      FROM t1
229e0b2d5daSdrh     WHERE value1 IN (SELECT max(value1) FROM t1 GROUP BY id1);
230e0b2d5daSdrh  }
231e0b2d5daSdrh} {12 2 34 4}
232e0b2d5daSdrhdo_test aggnested-3.15 {
233e0b2d5daSdrh  # FIXME:  If case 3.16 works, then this case really ought to work too...
234e0b2d5daSdrh  catchsql {
235e0b2d5daSdrh    SELECT max(value1), (SELECT sum(value2=max(value1)) FROM t2)
236e0b2d5daSdrh      FROM t1
237e0b2d5daSdrh     GROUP BY id1;
238e0b2d5daSdrh  }
239e0b2d5daSdrh} {1 {misuse of aggregate function max()}}
240e0b2d5daSdrhdo_test aggnested-3.16 {
241e0b2d5daSdrh  db eval {
242e0b2d5daSdrh    SELECT max(value1), (SELECT sum(value2=value1) FROM t2)
243e0b2d5daSdrh      FROM t1
244e0b2d5daSdrh     GROUP BY id1;
245e0b2d5daSdrh  }
246e0b2d5daSdrh} {12 2 34 4}
247e0b2d5daSdrh
24880f6bfc0Sdrh# 2019-08-31
24980f6bfc0Sdrh# Problem found by dbsqlfuzz
25080f6bfc0Sdrh#
25180f6bfc0Sdrhdo_execsql_test aggnested-4.1 {
25280f6bfc0Sdrh  DROP TABLE IF EXISTS aa;
25380f6bfc0Sdrh  DROP TABLE IF EXISTS bb;
25480f6bfc0Sdrh  CREATE TABLE aa(x INT);  INSERT INTO aa(x) VALUES(123);
25580f6bfc0Sdrh  CREATE TABLE bb(y INT);  INSERT INTO bb(y) VALUES(456);
25680f6bfc0Sdrh  SELECT (SELECT sum(x+(SELECT y)) FROM bb) FROM aa;
25780f6bfc0Sdrh} {579}
25880f6bfc0Sdrhdo_execsql_test aggnested-4.2 {
25980f6bfc0Sdrh  SELECT (SELECT sum(x+y) FROM bb) FROM aa;
26080f6bfc0Sdrh} {579}
26180f6bfc0Sdrhdo_execsql_test aggnested-4.3 {
26280f6bfc0Sdrh  DROP TABLE IF EXISTS tx;
26380f6bfc0Sdrh  DROP TABLE IF EXISTS ty;
26480f6bfc0Sdrh  CREATE TABLE tx(x INT);
26580f6bfc0Sdrh  INSERT INTO tx VALUES(1),(2),(3),(4),(5);
26680f6bfc0Sdrh  CREATE TABLE ty(y INT);
26780f6bfc0Sdrh  INSERT INTO ty VALUES(91),(92),(93);
26880f6bfc0Sdrh  SELECT min((SELECT count(y) FROM ty)) FROM tx;
26980f6bfc0Sdrh} {3}
27080f6bfc0Sdrhdo_execsql_test aggnested-4.4 {
27180f6bfc0Sdrh  SELECT max((SELECT a FROM (SELECT count(*) AS a FROM ty) AS s)) FROM tx;
27280f6bfc0Sdrh} {3}
27380f6bfc0Sdrh
274ed41a96bSdan#--------------------------------------------------------------------------
275ed41a96bSdan#
276ed41a96bSdanreset_db
277ed41a96bSdando_execsql_test 5.0 {
278ed41a96bSdan  CREATE TABLE x1(a, b);
279ed41a96bSdan  INSERT INTO x1 VALUES(1, 2);
280ed41a96bSdan  CREATE TABLE x2(x);
281ed41a96bSdan  INSERT INTO x2 VALUES(NULL), (NULL), (NULL);
282ed41a96bSdan}
283ed41a96bSdan
284ed41a96bSdan# At one point, aggregate "total()" in the query below was being processed
285ed41a96bSdan# as part of the outer SELECT, not as part of the sub-select with no FROM
286ed41a96bSdan# clause.
287ed41a96bSdando_execsql_test 5.1 {
288ed41a96bSdan  SELECT ( SELECT total( (SELECT b FROM x1) ) ) FROM x2;
289ed41a96bSdan} {2.0 2.0 2.0}
290ed41a96bSdan
291ed41a96bSdando_execsql_test 5.2 {
292ed41a96bSdan  SELECT ( SELECT total( (SELECT 2 FROM x1) ) ) FROM x2;
293ed41a96bSdan} {2.0 2.0 2.0}
294ed41a96bSdan
295ed41a96bSdando_execsql_test 5.3 {
296ed41a96bSdan  CREATE TABLE t1(a);
297ed41a96bSdan  CREATE TABLE t2(b);
298ed41a96bSdan}
299ed41a96bSdan
300ed41a96bSdando_execsql_test 5.4 {
301ed41a96bSdan  SELECT(
302ed41a96bSdan    SELECT max(b) LIMIT (
303ed41a96bSdan      SELECT total( (SELECT a FROM t1) )
304ed41a96bSdan    )
305ed41a96bSdan  )
306ed41a96bSdan  FROM t2;
307ed41a96bSdan} {{}}
308ed41a96bSdan
309ed41a96bSdando_execsql_test 5.5 {
310ed41a96bSdan  CREATE TABLE a(b);
311ed41a96bSdan  WITH c AS(SELECT a)
312ed41a96bSdan    SELECT(SELECT(SELECT group_concat(b, b)
313ed41a96bSdan          LIMIT(SELECT 0.100000 *
314ed41a96bSdan            AVG(DISTINCT(SELECT 0 FROM a ORDER BY b, b, b))))
315ed41a96bSdan        FROM a GROUP BY b,
316ed41a96bSdan        b, b) FROM a EXCEPT SELECT b FROM a ORDER BY b,
317ed41a96bSdan    b, b;
318ed41a96bSdan}
319ed41a96bSdan
320d59f9835Sdan#-------------------------------------------------------------------------
321d59f9835Sdan# dbsqlfuzz a779227f721a834df95f4f42d0c31550a1f8b8a2
322d59f9835Sdan#
323d59f9835Sdanreset_db
324d59f9835Sdando_execsql_test 6.0 {
325d59f9835Sdan  CREATE TABLE t1(a);
326d59f9835Sdan  CREATE TABLE t2(b);
327d59f9835Sdan
328d59f9835Sdan  INSERT INTO t1 VALUES('x');
329d59f9835Sdan  INSERT INTO t2 VALUES(1);
330d59f9835Sdan}
331d59f9835Sdan
332d59f9835Sdando_execsql_test 6.1.1 {
333d59f9835Sdan  SELECT (
334d59f9835Sdan    SELECT t2.b FROM (SELECT t2.b AS c FROM t1) GROUP BY 1 HAVING t2.b
335d59f9835Sdan  )
336d59f9835Sdan  FROM t2 GROUP BY 'constant_string';
337d59f9835Sdan} {1}
338d59f9835Sdando_execsql_test 6.1.2 {
339d59f9835Sdan  SELECT (
340d59f9835Sdan    SELECT c FROM (SELECT t2.b AS c FROM t1) GROUP BY c HAVING t2.b
341d59f9835Sdan  )
342d59f9835Sdan  FROM t2 GROUP BY 'constant_string';
343d59f9835Sdan} {1}
344d59f9835Sdan
345d59f9835Sdando_execsql_test 6.2.0 {
346d59f9835Sdan  UPDATE t2 SET b=0
347d59f9835Sdan}
348d59f9835Sdando_execsql_test 6.2.1 {
349d59f9835Sdan  SELECT (
350d59f9835Sdan    SELECT t2.b FROM (SELECT t2.b AS c FROM t1) GROUP BY 1 HAVING t2.b
351d59f9835Sdan  )
352d59f9835Sdan  FROM t2 GROUP BY 'constant_string';
353d59f9835Sdan} {{}}
354d59f9835Sdando_execsql_test 6.2.2 {
355d59f9835Sdan  SELECT (
356d59f9835Sdan    SELECT c FROM (SELECT t2.b AS c FROM t1) GROUP BY c HAVING t2.b
357d59f9835Sdan  )
358d59f9835Sdan  FROM t2 GROUP BY 'constant_string';
359d59f9835Sdan} {{}}
360d59f9835Sdan
361d59f9835Sdan
36280f6bfc0Sdrh
36380f6bfc0Sdrh
364e0b2d5daSdrh
365030796dfSdrhfinish_test
366