blob: 64a1a6fe966c0deaf512a819ada56c9aef17e90a [file] [log] [blame]
drh5cf8e8c2002-02-19 22:42:05 +00001# 2001 September 15
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. The
12# focus of this file is testing SELECT statements that contain
13# aggregate min() and max() functions and which are handled as
14# as a special case.
15#
danielk197727c77432004-11-22 13:35:41 +000016# $Id: minmax.test,v 1.14 2004/11/22 13:35:42 danielk1977 Exp $
drh5cf8e8c2002-02-19 22:42:05 +000017
18set testdir [file dirname $argv0]
19source $testdir/tester.tcl
20
21do_test minmax-1.0 {
22 execsql {
23 BEGIN;
24 CREATE TABLE t1(x, y);
25 INSERT INTO t1 VALUES(1,1);
26 INSERT INTO t1 VALUES(2,2);
27 INSERT INTO t1 VALUES(3,2);
28 INSERT INTO t1 VALUES(4,3);
29 INSERT INTO t1 VALUES(5,3);
30 INSERT INTO t1 VALUES(6,3);
31 INSERT INTO t1 VALUES(7,3);
32 INSERT INTO t1 VALUES(8,4);
33 INSERT INTO t1 VALUES(9,4);
34 INSERT INTO t1 VALUES(10,4);
35 INSERT INTO t1 VALUES(11,4);
36 INSERT INTO t1 VALUES(12,4);
37 INSERT INTO t1 VALUES(13,4);
38 INSERT INTO t1 VALUES(14,4);
39 INSERT INTO t1 VALUES(15,4);
40 INSERT INTO t1 VALUES(16,5);
41 INSERT INTO t1 VALUES(17,5);
42 INSERT INTO t1 VALUES(18,5);
43 INSERT INTO t1 VALUES(19,5);
44 INSERT INTO t1 VALUES(20,5);
45 COMMIT;
46 SELECT DISTINCT y FROM t1 ORDER BY y;
47 }
48} {1 2 3 4 5}
49
50do_test minmax-1.1 {
51 set sqlite_search_count 0
52 execsql {SELECT min(x) FROM t1}
53} {1}
54do_test minmax-1.2 {
55 set sqlite_search_count
56} {19}
57do_test minmax-1.3 {
58 set sqlite_search_count 0
59 execsql {SELECT max(x) FROM t1}
60} {20}
61do_test minmax-1.4 {
62 set sqlite_search_count
63} {19}
64do_test minmax-1.5 {
65 execsql {CREATE INDEX t1i1 ON t1(x)}
66 set sqlite_search_count 0
67 execsql {SELECT min(x) FROM t1}
68} {1}
69do_test minmax-1.6 {
70 set sqlite_search_count
drh1af3fdb2004-07-18 21:33:01 +000071} {2}
drh5cf8e8c2002-02-19 22:42:05 +000072do_test minmax-1.7 {
73 set sqlite_search_count 0
74 execsql {SELECT max(x) FROM t1}
75} {20}
76do_test minmax-1.8 {
77 set sqlite_search_count
78} {1}
79do_test minmax-1.9 {
80 set sqlite_search_count 0
81 execsql {SELECT max(y) FROM t1}
82} {5}
83do_test minmax-1.10 {
84 set sqlite_search_count
85} {19}
86
87do_test minmax-2.0 {
88 execsql {
89 CREATE TABLE t2(a INTEGER PRIMARY KEY, b);
90 INSERT INTO t2 SELECT * FROM t1;
91 }
92 set sqlite_search_count 0
93 execsql {SELECT min(a) FROM t2}
94} {1}
95do_test minmax-2.1 {
96 set sqlite_search_count
97} {0}
98do_test minmax-2.2 {
99 set sqlite_search_count 0
100 execsql {SELECT max(a) FROM t2}
101} {20}
102do_test minmax-2.3 {
103 set sqlite_search_count
104} {0}
105
106do_test minmax-3.0 {
107 execsql {INSERT INTO t2 VALUES((SELECT max(a) FROM t2)+1,999)}
108 set sqlite_search_count 0
109 execsql {SELECT max(a) FROM t2}
110} {21}
111do_test minmax-3.1 {
112 set sqlite_search_count
113} {0}
114do_test minmax-3.2 {
115 execsql {INSERT INTO t2 VALUES((SELECT max(a) FROM t2)+1,999)}
116 set sqlite_search_count 0
117 execsql {
118 SELECT b FROM t2 WHERE a=(SELECT max(a) FROM t2)
119 }
120} {999}
121do_test minmax-3.3 {
122 set sqlite_search_count
123} {0}
124
danielk197727c77432004-11-22 13:35:41 +0000125ifcapable compound {
drhbb113512002-05-27 01:04:51 +0000126do_test minmax-4.1 {
127 execsql {
drh268380c2004-02-25 13:47:31 +0000128 SELECT coalesce(min(x+0),-1), coalesce(max(x+0),-1) FROM
drhbb113512002-05-27 01:04:51 +0000129 (SELECT * FROM t1 UNION SELECT NULL as 'x', NULL as 'y')
130 }
drh9eb516c2004-07-18 20:52:32 +0000131} {1 20}
drhf570f012002-05-31 15:51:25 +0000132do_test minmax-4.2 {
133 execsql {
134 SELECT y, sum(x) FROM
135 (SELECT null, y+1 FROM t1 UNION SELECT * FROM t1)
136 GROUP BY y ORDER BY y;
137 }
drh92febd92004-08-20 18:34:20 +0000138} {1 1.0 2 5.0 3 22.0 4 92.0 5 90.0 6 0.0}
drhf570f012002-05-31 15:51:25 +0000139do_test minmax-4.3 {
140 execsql {
141 SELECT y, count(x), count(*) FROM
142 (SELECT null, y+1 FROM t1 UNION SELECT * FROM t1)
143 GROUP BY y ORDER BY y;
144 }
145} {1 1 1 2 2 3 3 4 5 4 8 9 5 5 6 6 0 1}
danielk197727c77432004-11-22 13:35:41 +0000146} ;# ifcapable compound
drh5cf8e8c2002-02-19 22:42:05 +0000147
drhd4d595f2003-04-17 12:44:23 +0000148# Make sure the min(x) and max(x) optimizations work on empty tables
149# including empty tables with indices. Ticket #296.
150#
151do_test minmax-5.1 {
152 execsql {
153 CREATE TABLE t3(x INTEGER UNIQUE NOT NULL);
154 SELECT coalesce(min(x),999) FROM t3;
155 }
156} {999}
157do_test minmax-5.2 {
158 execsql {
159 SELECT coalesce(min(rowid),999) FROM t3;
160 }
161} {999}
162do_test minmax-5.3 {
163 execsql {
164 SELECT coalesce(max(x),999) FROM t3;
165 }
166} {999}
167do_test minmax-5.4 {
168 execsql {
169 SELECT coalesce(max(rowid),999) FROM t3;
170 }
171} {999}
172do_test minmax-5.5 {
173 execsql {
174 SELECT coalesce(max(rowid),999) FROM t3 WHERE rowid<25;
175 }
176} {999}
177
drhe5f50722003-07-19 00:44:14 +0000178# Make sure the min(x) and max(x) optimizations work when there
179# is a LIMIT clause. Ticket #396.
180#
181do_test minmax-6.1 {
182 execsql {
183 SELECT min(a) FROM t2 LIMIT 1
184 }
185} {1}
186do_test minmax-6.2 {
187 execsql {
188 SELECT max(a) FROM t2 LIMIT 3
189 }
190} {22}
191do_test minmax-6.3 {
192 execsql {
193 SELECT min(a) FROM t2 LIMIT 0,100
194 }
195} {1}
196do_test minmax-6.4 {
197 execsql {
198 SELECT max(a) FROM t2 LIMIT 1,100
199 }
200} {}
201do_test minmax-6.5 {
202 execsql {
203 SELECT min(x) FROM t3 LIMIT 1
204 }
205} {{}}
206do_test minmax-6.6 {
207 execsql {
208 SELECT max(x) FROM t3 LIMIT 0
209 }
210} {}
211do_test minmax-6.7 {
212 execsql {
213 SELECT max(a) FROM t2 LIMIT 0
214 }
215} {}
216
drh0c37e632004-01-30 02:01:03 +0000217# Make sure the max(x) and min(x) optimizations work for nested
218# queries. Ticket #587.
219#
220do_test minmax-7.1 {
221 execsql {
222 SELECT max(x) FROM t1;
223 }
224} 20
225do_test minmax-7.2 {
226 execsql {
227 SELECT * FROM (SELECT max(x) FROM t1);
228 }
229} 20
230do_test minmax-7.3 {
231 execsql {
232 SELECT min(x) FROM t1;
233 }
234} 1
235do_test minmax-7.4 {
236 execsql {
237 SELECT * FROM (SELECT min(x) FROM t1);
238 }
239} 1
240
drh268380c2004-02-25 13:47:31 +0000241# Make sure min(x) and max(x) work correctly when the datatype is
242# TEXT instead of NUMERIC. Ticket #623.
243#
244do_test minmax-8.1 {
245 execsql {
246 CREATE TABLE t4(a TEXT);
247 INSERT INTO t4 VALUES('1234');
248 INSERT INTO t4 VALUES('234');
249 INSERT INTO t4 VALUES('34');
250 SELECT min(a), max(a) FROM t4;
251 }
252} {1234 34}
253do_test minmax-8.2 {
254 execsql {
255 CREATE TABLE t5(a INTEGER);
256 INSERT INTO t5 VALUES('1234');
257 INSERT INTO t5 VALUES('234');
258 INSERT INTO t5 VALUES('34');
259 SELECT min(a), max(a) FROM t5;
260 }
261} {34 1234}
262
drh6e175292004-03-13 14:00:36 +0000263# Ticket #658: Test the min()/max() optimization when the FROM clause
264# is a subquery.
265#
danielk197727c77432004-11-22 13:35:41 +0000266ifcapable compound {
drh6e175292004-03-13 14:00:36 +0000267do_test minmax-9.1 {
268 execsql {
269 SELECT max(rowid) FROM (
270 SELECT max(rowid) FROM t4 UNION SELECT max(rowid) FROM t5
271 )
272 }
273} {1}
274do_test minmax-9.2 {
275 execsql {
276 SELECT max(rowid) FROM (
277 SELECT max(rowid) FROM t4 EXCEPT SELECT max(rowid) FROM t5
278 )
279 }
280} {{}}
danielk197727c77432004-11-22 13:35:41 +0000281} ;# ifcapable compound
drhd4d595f2003-04-17 12:44:23 +0000282
drh9eb516c2004-07-18 20:52:32 +0000283# If there is a NULL in an aggregate max() or min(), ignore it. An
284# aggregate min() or max() will only return NULL if all values are NULL.
danielk19773aeab9e2004-06-24 00:20:04 +0000285#
286do_test minmax-10.1 {
287 execsql {
288 CREATE TABLE t6(x);
289 INSERT INTO t6 VALUES(1);
290 INSERT INTO t6 VALUES(2);
291 INSERT INTO t6 VALUES(NULL);
292 SELECT coalesce(min(x),-1) FROM t6;
293 }
drh9eb516c2004-07-18 20:52:32 +0000294} {1}
danielk19773aeab9e2004-06-24 00:20:04 +0000295do_test minmax-10.2 {
296 execsql {
297 SELECT max(x) FROM t6;
298 }
299} {2}
300do_test minmax-10.3 {
301 execsql {
302 CREATE INDEX i6 ON t6(x);
303 SELECT coalesce(min(x),-1) FROM t6;
304 }
drh9eb516c2004-07-18 20:52:32 +0000305} {1}
danielk19773aeab9e2004-06-24 00:20:04 +0000306do_test minmax-10.4 {
307 execsql {
308 SELECT max(x) FROM t6;
309 }
310} {2}
drh9eb516c2004-07-18 20:52:32 +0000311do_test minmax-10.5 {
312 execsql {
313 DELETE FROM t6 WHERE x NOT NULL;
314 SELECT count(*) FROM t6;
315 }
316} 1
317do_test minmax-10.6 {
318 execsql {
319 SELECT count(x) FROM t6;
320 }
321} 0
322do_test minmax-10.7 {
323 execsql {
324 SELECT (SELECT min(x) FROM t6), (SELECT max(x) FROM t6);
325 }
326} {{} {}}
327do_test minmax-10.8 {
328 execsql {
329 SELECT min(x), max(x) FROM t6;
330 }
331} {{} {}}
332do_test minmax-10.9 {
333 execsql {
334 INSERT INTO t6 SELECT * FROM t6;
335 INSERT INTO t6 SELECT * FROM t6;
336 INSERT INTO t6 SELECT * FROM t6;
337 INSERT INTO t6 SELECT * FROM t6;
338 INSERT INTO t6 SELECT * FROM t6;
339 INSERT INTO t6 SELECT * FROM t6;
340 INSERT INTO t6 SELECT * FROM t6;
341 INSERT INTO t6 SELECT * FROM t6;
342 INSERT INTO t6 SELECT * FROM t6;
343 INSERT INTO t6 SELECT * FROM t6;
344 SELECT count(*) FROM t6;
345 }
346} 1024
347do_test minmax-10.10 {
348 execsql {
349 SELECT count(x) FROM t6;
350 }
351} 0
352do_test minmax-10.11 {
353 execsql {
354 SELECT (SELECT min(x) FROM t6), (SELECT max(x) FROM t6);
355 }
356} {{} {}}
357do_test minmax-10.12 {
358 execsql {
359 SELECT min(x), max(x) FROM t6;
360 }
361} {{} {}}
362
danielk19773aeab9e2004-06-24 00:20:04 +0000363
drh5cf8e8c2002-02-19 22:42:05 +0000364finish_test