xref: /sqlite-3.40.0/test/aggnested.test (revision e0b2d5da)
1# 2012 August 23
2#
3# The author disclaims copyright to this source code.  In place of
4# a legal notice, here is a blessing:
5#
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.
9#
10#***********************************************************************
11# This file implements regression tests for SQLite library.
12#
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
16#
17
18set testdir [file dirname $argv0]
19source $testdir/tester.tcl
20
21do_test aggnested-1.1 {
22  db eval {
23    CREATE TABLE t1(a1 INTEGER);
24    INSERT INTO t1 VALUES(1), (2), (3);
25    CREATE TABLE t2(b1 INTEGER);
26    INSERT INTO t2 VALUES(4), (5);
27    SELECT (SELECT group_concat(a1,'x') FROM t2) FROM t1;
28  }
29} {1x2x3}
30do_test aggnested-1.2 {
31  db eval {
32    SELECT
33     (SELECT group_concat(a1,'x') || '-' || group_concat(b1,'y') FROM t2)
34    FROM t1;
35  }
36} {1x2x3-4y5}
37do_test aggnested-1.3 {
38  db eval {
39    SELECT (SELECT group_concat(b1,a1) FROM t2) FROM t1;
40  }
41} {415 425 435}
42do_test aggnested-1.4 {
43  db eval {
44    SELECT (SELECT group_concat(a1,b1) FROM t2) FROM t1;
45  }
46} {151 252 353}
47
48
49# This test case is a copy of the one in
50# http://www.mail-archive.com/[email protected]/msg70787.html
51#
52do_test aggnested-2.0 {
53  sqlite3 db2 :memory:
54  db2 eval {
55    CREATE TABLE t1 (A1 INTEGER NOT NULL,A2 INTEGER NOT NULL,A3 INTEGER NOT
56    NULL,A4 INTEGER NOT NULL,PRIMARY KEY(A1));
57    REPLACE INTO t1 VALUES(1,11,111,1111);
58    REPLACE INTO t1 VALUES(2,22,222,2222);
59    REPLACE INTO t1 VALUES(3,33,333,3333);
60    CREATE TABLE t2 (B1 INTEGER NOT NULL,B2 INTEGER NOT NULL,B3 INTEGER NOT
61    NULL,B4 INTEGER NOT NULL,PRIMARY KEY(B1));
62    REPLACE INTO t2 VALUES(1,88,888,8888);
63    REPLACE INTO t2 VALUES(2,99,999,9999);
64    SELECT (SELECT GROUP_CONCAT(CASE WHEN a1=1 THEN'A' ELSE 'B' END) FROM t2),
65            t1.*
66    FROM t1;
67  }
68} {A,B,B 3 33 333 3333}
69db2 close
70
71##################### Test cases for ticket [bfbf38e5e9956ac69f] ############
72#
73# This first test case is the original problem report:
74do_test aggnested-3.0 {
75  db eval {
76    CREATE TABLE AAA (
77      aaa_id       INTEGER PRIMARY KEY AUTOINCREMENT
78    );
79    CREATE TABLE RRR (
80      rrr_id      INTEGER     PRIMARY KEY AUTOINCREMENT,
81      rrr_date    INTEGER     NOT NULL,
82      rrr_aaa     INTEGER
83    );
84    CREATE TABLE TTT (
85      ttt_id      INTEGER PRIMARY KEY AUTOINCREMENT,
86      target_aaa  INTEGER NOT NULL,
87      source_aaa  INTEGER NOT NULL
88    );
89    insert into AAA (aaa_id) values (2);
90    insert into TTT (ttt_id, target_aaa, source_aaa)
91    values (4469, 2, 2);
92    insert into TTT (ttt_id, target_aaa, source_aaa)
93    values (4476, 2, 1);
94    insert into RRR (rrr_id, rrr_date, rrr_aaa)
95    values (0, 0, NULL);
96    insert into RRR (rrr_id, rrr_date, rrr_aaa)
97    values (2, 4312, 2);
98    SELECT i.aaa_id,
99      (SELECT sum(CASE WHEN (t.source_aaa == i.aaa_id) THEN 1 ELSE 0 END)
100         FROM TTT t
101      ) AS segfault
102    FROM
103     (SELECT curr.rrr_aaa as aaa_id
104        FROM RRR curr
105          -- you also can comment out the next line
106          -- it causes segfault to happen after one row is outputted
107          INNER JOIN AAA a ON (curr.rrr_aaa = aaa_id)
108          LEFT JOIN RRR r ON (r.rrr_id <> 0 AND r.rrr_date < curr.rrr_date)
109       GROUP BY curr.rrr_id
110      HAVING r.rrr_date IS NULL
111    ) i;
112  }
113} {2 1}
114
115# Further variants of the test case, as found in the ticket
116#
117do_test aggnested-3.1 {
118  db eval {
119    DROP TABLE IF EXISTS t1;
120    DROP TABLE IF EXISTS t2;
121    CREATE TABLE t1 (
122      id1 INTEGER PRIMARY KEY AUTOINCREMENT,
123      value1 INTEGER
124    );
125    INSERT INTO t1 VALUES(4469,2),(4476,1);
126    CREATE TABLE t2 (
127      id2 INTEGER PRIMARY KEY AUTOINCREMENT,
128      value2 INTEGER
129    );
130    INSERT INTO t2 VALUES(0,1),(2,2);
131    SELECT
132     (SELECT sum(value2==xyz) FROM t2)
133    FROM
134     (SELECT curr.value1 as xyz
135        FROM t1 AS curr LEFT JOIN t1 AS other
136       GROUP BY curr.id1);
137  }
138} {1 1}
139do_test aggnested-3.2 {
140  db eval {
141    DROP TABLE IF EXISTS t1;
142    DROP TABLE IF EXISTS t2;
143    CREATE TABLE t1 (
144      id1 INTEGER,
145      value1 INTEGER,
146      x1 INTEGER
147    );
148    INSERT INTO t1 VALUES(4469,2,98),(4469,1,99),(4469,3,97);
149    CREATE TABLE t2 (
150      value2 INTEGER
151    );
152    INSERT INTO t2 VALUES(1);
153    SELECT
154     (SELECT sum(value2==xyz) FROM t2)
155    FROM
156     (SELECT value1 as xyz, max(x1) AS pqr
157        FROM t1
158       GROUP BY id1);
159  }
160} {0}
161do_test aggnested-3.3 {
162  db eval {
163    DROP TABLE IF EXISTS t1;
164    DROP TABLE IF EXISTS t2;
165    CREATE TABLE t1(id1, value1);
166    INSERT INTO t1 VALUES(4469,2),(4469,1);
167    CREATE TABLE t2 (value2);
168    INSERT INTO t2 VALUES(1);
169    SELECT (SELECT sum(value2=value1) FROM t2), max(value1)
170      FROM t1
171     GROUP BY id1;
172  }
173} {0 2}
174
175# A batch of queries all doing approximately the same operation involving
176# two nested aggregate queries.
177#
178do_test aggnested-3.11 {
179  db eval {
180    DROP TABLE IF EXISTS t1;
181    DROP TABLE IF EXISTS t2;
182    CREATE TABLE t1(id1, value1);
183    INSERT INTO t1 VALUES(4469,12),(4469,11),(4470,34);
184    CREATE INDEX t1id1 ON t1(id1);
185    CREATE TABLE t2 (value2);
186    INSERT INTO t2 VALUES(12),(34),(34);
187    INSERT INTO t2 SELECT value2 FROM t2;
188
189    SELECT max(value1), (SELECT count(*) FROM t2 WHERE value2=max(value1))
190      FROM t1
191     GROUP BY id1;
192  }
193} {12 2 34 4}
194do_test aggnested-3.12 {
195  db eval {
196    SELECT max(value1), (SELECT count(*) FROM t2 WHERE value2=value1)
197      FROM t1
198     GROUP BY id1;
199  }
200} {12 2 34 4}
201do_test aggnested-3.13 {
202  db eval {
203    SELECT value1, (SELECT sum(value2=value1) FROM t2)
204      FROM t1;
205  }
206} {12 2 11 0 34 4}
207do_test aggnested-3.14 {
208  db eval {
209    SELECT value1, (SELECT sum(value2=value1) FROM t2)
210      FROM t1
211     WHERE value1 IN (SELECT max(value1) FROM t1 GROUP BY id1);
212  }
213} {12 2 34 4}
214do_test aggnested-3.15 {
215  # FIXME:  If case 3.16 works, then this case really ought to work too...
216  catchsql {
217    SELECT max(value1), (SELECT sum(value2=max(value1)) FROM t2)
218      FROM t1
219     GROUP BY id1;
220  }
221} {1 {misuse of aggregate function max()}}
222do_test aggnested-3.16 {
223  db eval {
224    SELECT max(value1), (SELECT sum(value2=value1) FROM t2)
225      FROM t1
226     GROUP BY id1;
227  }
228} {12 2 34 4}
229
230
231finish_test
232