xref: /sqlite-3.40.0/test/select4.test (revision ef5ecb41)
1# 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 UNION, INTERSECT and EXCEPT operators
13# in SELECT statements.
14#
15# $Id: select4.test,v 1.16 2004/05/27 17:22:56 drh Exp $
16
17set testdir [file dirname $argv0]
18source $testdir/tester.tcl
19
20# Build some test data
21#
22execsql {
23  CREATE TABLE t1(n int, log int);
24  BEGIN;
25}
26for {set i 1} {$i<32} {incr i} {
27  for {set j 0} {pow(2,$j)<$i} {incr j} {}
28  execsql "INSERT INTO t1 VALUES($i,$j)"
29}
30execsql {
31  COMMIT;
32}
33
34do_test select4-1.0 {
35  execsql {SELECT DISTINCT log FROM t1 ORDER BY log}
36} {0 1 2 3 4 5}
37
38# Union All operator
39#
40do_test select4-1.1a {
41  lsort [execsql {SELECT DISTINCT log FROM t1}]
42} {0 1 2 3 4 5}
43do_test select4-1.1b {
44  lsort [execsql {SELECT n FROM t1 WHERE log=3}]
45} {5 6 7 8}
46do_test select4-1.1c {
47  execsql {
48    SELECT DISTINCT log FROM t1
49    UNION ALL
50    SELECT n FROM t1 WHERE log=3
51    ORDER BY log;
52  }
53} {0 1 2 3 4 5 5 6 7 8}
54do_test select4-1.1d {
55  execsql {
56    CREATE TABLE t2 AS
57      SELECT DISTINCT log FROM t1
58      UNION ALL
59      SELECT n FROM t1 WHERE log=3
60      ORDER BY log;
61    SELECT * FROM t2;
62  }
63} {0 1 2 3 4 5 5 6 7 8}
64execsql {DROP TABLE t2}
65do_test select4-1.1e {
66  execsql {
67    CREATE TABLE t2 AS
68      SELECT DISTINCT log FROM t1
69      UNION ALL
70      SELECT n FROM t1 WHERE log=3
71      ORDER BY log DESC;
72    SELECT * FROM t2;
73  }
74} {8 7 6 5 5 4 3 2 1 0}
75execsql {DROP TABLE t2}
76do_test select4-1.1f {
77  execsql {
78    SELECT DISTINCT log FROM t1
79    UNION ALL
80    SELECT n FROM t1 WHERE log=2
81  }
82} {0 1 2 3 4 5 3 4}
83do_test select4-1.1g {
84  execsql {
85    CREATE TABLE t2 AS
86      SELECT DISTINCT log FROM t1
87      UNION ALL
88      SELECT n FROM t1 WHERE log=2;
89    SELECT * FROM t2;
90  }
91} {0 1 2 3 4 5 3 4}
92execsql {DROP TABLE t2}
93do_test select4-1.2 {
94  execsql {
95    SELECT log FROM t1 WHERE n IN
96      (SELECT DISTINCT log FROM t1 UNION ALL
97       SELECT n FROM t1 WHERE log=3)
98    ORDER BY log;
99  }
100} {0 1 2 2 3 3 3 3}
101do_test select4-1.3 {
102  set v [catch {execsql {
103    SELECT DISTINCT log FROM t1 ORDER BY log
104    UNION ALL
105    SELECT n FROM t1 WHERE log=3
106    ORDER BY log;
107  }} msg]
108  lappend v $msg
109} {1 {ORDER BY clause should come after UNION ALL not before}}
110
111# Union operator
112#
113do_test select4-2.1 {
114  execsql {
115    SELECT DISTINCT log FROM t1
116    UNION
117    SELECT n FROM t1 WHERE log=3
118    ORDER BY log;
119  }
120} {0 1 2 3 4 5 6 7 8}
121do_test select4-2.2 {
122  execsql {
123    SELECT log FROM t1 WHERE n IN
124      (SELECT DISTINCT log FROM t1 UNION
125       SELECT n FROM t1 WHERE log=3)
126    ORDER BY log;
127  }
128} {0 1 2 2 3 3 3 3}
129do_test select4-2.3 {
130  set v [catch {execsql {
131    SELECT DISTINCT log FROM t1 ORDER BY log
132    UNION
133    SELECT n FROM t1 WHERE log=3
134    ORDER BY log;
135  }} msg]
136  lappend v $msg
137} {1 {ORDER BY clause should come after UNION not before}}
138
139# Except operator
140#
141do_test select4-3.1.1 {
142  execsql {
143    SELECT DISTINCT log FROM t1
144    EXCEPT
145    SELECT n FROM t1 WHERE log=3
146    ORDER BY log;
147  }
148} {0 1 2 3 4}
149do_test select4-3.1.2 {
150  execsql {
151    CREATE TABLE t2 AS
152      SELECT DISTINCT log FROM t1
153      EXCEPT
154      SELECT n FROM t1 WHERE log=3
155      ORDER BY log;
156    SELECT * FROM t2;
157  }
158} {0 1 2 3 4}
159execsql {DROP TABLE t2}
160do_test select4-3.1.3 {
161  execsql {
162    CREATE TABLE t2 AS
163      SELECT DISTINCT log FROM t1
164      EXCEPT
165      SELECT n FROM t1 WHERE log=3
166      ORDER BY log DESC;
167    SELECT * FROM t2;
168  }
169} {4 3 2 1 0}
170execsql {DROP TABLE t2}
171do_test select4-3.2 {
172  execsql {
173    SELECT log FROM t1 WHERE n IN
174      (SELECT DISTINCT log FROM t1 EXCEPT
175       SELECT n FROM t1 WHERE log=3)
176    ORDER BY log;
177  }
178} {0 1 2 2}
179do_test select4-3.3 {
180  set v [catch {execsql {
181    SELECT DISTINCT log FROM t1 ORDER BY log
182    EXCEPT
183    SELECT n FROM t1 WHERE log=3
184    ORDER BY log;
185  }} msg]
186  lappend v $msg
187} {1 {ORDER BY clause should come after EXCEPT not before}}
188
189# Intersect operator
190#
191do_test select4-4.1.1 {
192  execsql {
193    SELECT DISTINCT log FROM t1
194    INTERSECT
195    SELECT n FROM t1 WHERE log=3
196    ORDER BY log;
197  }
198} {5}
199
200do_test select4-4.1.2 {
201  execsql {
202    SELECT DISTINCT log FROM t1 UNION ALL SELECT 6
203    INTERSECT
204    SELECT n FROM t1 WHERE log=3
205    ORDER BY log;
206  }
207} {5 6}
208do_test select4-4.1.3 {
209  execsql {
210    CREATE TABLE t2 AS
211      SELECT DISTINCT log FROM t1 UNION ALL SELECT 6
212      INTERSECT
213      SELECT n FROM t1 WHERE log=3
214      ORDER BY log;
215    SELECT * FROM t2;
216  }
217} {5 6}
218execsql {DROP TABLE t2}
219do_test select4-4.1.4 {
220  execsql {
221    CREATE TABLE t2 AS
222      SELECT DISTINCT log FROM t1 UNION ALL SELECT 6
223      INTERSECT
224      SELECT n FROM t1 WHERE log=3
225      ORDER BY log DESC;
226    SELECT * FROM t2;
227  }
228} {6 5}
229execsql {DROP TABLE t2}
230do_test select4-4.2 {
231  execsql {
232    SELECT log FROM t1 WHERE n IN
233      (SELECT DISTINCT log FROM t1 INTERSECT
234       SELECT n FROM t1 WHERE log=3)
235    ORDER BY log;
236  }
237} {3}
238do_test select4-4.3 {
239  set v [catch {execsql {
240    SELECT DISTINCT log FROM t1 ORDER BY log
241    INTERSECT
242    SELECT n FROM t1 WHERE log=3
243    ORDER BY log;
244  }} msg]
245  lappend v $msg
246} {1 {ORDER BY clause should come after INTERSECT not before}}
247
248# Various error messages while processing UNION or INTERSECT
249#
250do_test select4-5.1 {
251  set v [catch {execsql {
252    SELECT DISTINCT log FROM t2
253    UNION ALL
254    SELECT n FROM t1 WHERE log=3
255    ORDER BY log;
256  }} msg]
257  lappend v $msg
258} {1 {no such table: t2}}
259do_test select4-5.2 {
260  set v [catch {execsql {
261    SELECT DISTINCT log AS "xyzzy" FROM t1
262    UNION ALL
263    SELECT n FROM t1 WHERE log=3
264    ORDER BY xyzzy;
265  }} msg]
266  lappend v $msg
267} {0 {0 1 2 3 4 5 5 6 7 8}}
268do_test select4-5.2b {
269  set v [catch {execsql {
270    SELECT DISTINCT log AS xyzzy FROM t1
271    UNION ALL
272    SELECT n FROM t1 WHERE log=3
273    ORDER BY 'xyzzy';
274  }} msg]
275  lappend v $msg
276} {0 {0 1 2 3 4 5 5 6 7 8}}
277do_test select4-5.2c {
278  set v [catch {execsql {
279    SELECT DISTINCT log FROM t1
280    UNION ALL
281    SELECT n FROM t1 WHERE log=3
282    ORDER BY 'xyzzy';
283  }} msg]
284  lappend v $msg
285} {1 {ORDER BY term number 1 does not match any result column}}
286do_test select4-5.2d {
287  set v [catch {execsql {
288    SELECT DISTINCT log FROM t1
289    INTERSECT
290    SELECT n FROM t1 WHERE log=3
291    ORDER BY 'xyzzy';
292  }} msg]
293  lappend v $msg
294} {1 {ORDER BY term number 1 does not match any result column}}
295do_test select4-5.2e {
296  set v [catch {execsql {
297    SELECT DISTINCT log FROM t1
298    UNION ALL
299    SELECT n FROM t1 WHERE log=3
300    ORDER BY n;
301  }} msg]
302  lappend v $msg
303} {0 {0 1 2 3 4 5 5 6 7 8}}
304do_test select4-5.2f {
305  catchsql {
306    SELECT DISTINCT log FROM t1
307    UNION ALL
308    SELECT n FROM t1 WHERE log=3
309    ORDER BY log;
310  }
311} {0 {0 1 2 3 4 5 5 6 7 8}}
312do_test select4-5.2g {
313  catchsql {
314    SELECT DISTINCT log FROM t1
315    UNION ALL
316    SELECT n FROM t1 WHERE log=3
317    ORDER BY 1;
318  }
319} {0 {0 1 2 3 4 5 5 6 7 8}}
320do_test select4-5.2h {
321  catchsql {
322    SELECT DISTINCT log FROM t1
323    UNION ALL
324    SELECT n FROM t1 WHERE log=3
325    ORDER BY 2;
326  }
327} {1 {ORDER BY position 2 should be between 1 and 1}}
328do_test select4-5.2i {
329  catchsql {
330    SELECT DISTINCT 1, log FROM t1
331    UNION ALL
332    SELECT 2, n FROM t1 WHERE log=3
333    ORDER BY 2, 1;
334  }
335} {0 {1 0 1 1 1 2 1 3 1 4 1 5 2 5 2 6 2 7 2 8}}
336do_test select4-5.2j {
337  catchsql {
338    SELECT DISTINCT 1, log FROM t1
339    UNION ALL
340    SELECT 2, n FROM t1 WHERE log=3
341    ORDER BY 1, 2 DESC;
342  }
343} {0 {1 5 1 4 1 3 1 2 1 1 1 0 2 8 2 7 2 6 2 5}}
344do_test select4-5.2k {
345  catchsql {
346    SELECT DISTINCT 1, log FROM t1
347    UNION ALL
348    SELECT 2, n FROM t1 WHERE log=3
349    ORDER BY n, 1;
350  }
351} {0 {1 0 1 1 1 2 1 3 1 4 1 5 2 5 2 6 2 7 2 8}}
352do_test select4-5.3 {
353  set v [catch {execsql {
354    SELECT DISTINCT log, n FROM t1
355    UNION ALL
356    SELECT n FROM t1 WHERE log=3
357    ORDER BY log;
358  }} msg]
359  lappend v $msg
360} {1 {SELECTs to the left and right of UNION ALL do not have the same number of result columns}}
361do_test select4-5.4 {
362  set v [catch {execsql {
363    SELECT log FROM t1 WHERE n=2
364    UNION ALL
365    SELECT log FROM t1 WHERE n=3
366    UNION ALL
367    SELECT log FROM t1 WHERE n=4
368    UNION ALL
369    SELECT log FROM t1 WHERE n=5
370    ORDER BY log;
371  }} msg]
372  lappend v $msg
373} {0 {1 2 2 3}}
374
375do_test select4-6.1 {
376  execsql {
377    SELECT log, count(*) as cnt FROM t1 GROUP BY log
378    UNION
379    SELECT log, n FROM t1 WHERE n=7
380    ORDER BY cnt, log;
381  }
382} {0 1 1 1 2 2 3 4 3 7 4 8 5 15}
383do_test select4-6.2 {
384  execsql {
385    SELECT log, count(*) FROM t1 GROUP BY log
386    UNION
387    SELECT log, n FROM t1 WHERE n=7
388    ORDER BY count(*), log;
389  }
390} {0 1 1 1 2 2 3 4 3 7 4 8 5 15}
391
392# NULLs are indistinct for the UNION operator.
393# Make sure the UNION operator recognizes this
394#
395do_test select4-6.3 {
396  execsql {
397    SELECT NULL UNION SELECT NULL UNION
398    SELECT 1 UNION SELECT 2 AS 'x'
399    ORDER BY x;
400  }
401} {{} 1 2}
402do_test select4-6.3.1 {
403  execsql {
404    SELECT NULL UNION ALL SELECT NULL UNION ALL
405    SELECT 1 UNION ALL SELECT 2 AS 'x'
406    ORDER BY x;
407  }
408} {{} {} 1 2}
409
410# Make sure the DISTINCT keyword treats NULLs as indistinct.
411#
412do_test select4-6.4 {
413  execsql {
414    SELECT * FROM (
415       SELECT NULL, 1 UNION ALL SELECT NULL, 1
416    );
417  }
418} {{} 1 {} 1}
419do_test select4-6.5 {
420  execsql {
421    SELECT DISTINCT * FROM (
422       SELECT NULL, 1 UNION ALL SELECT NULL, 1
423    );
424  }
425} {{} 1}
426do_test select4-6.6 {
427  execsql {
428    SELECT DISTINCT * FROM (
429       SELECT 1,2  UNION ALL SELECT 1,2
430    );
431  }
432} {1 2}
433
434# Test distinctness of NULL in other ways.
435#
436do_test select4-6.7 {
437  execsql {
438    SELECT NULL EXCEPT SELECT NULL
439  }
440} {}
441
442
443# Make sure column names are correct when a compound select appears as
444# an expression in the WHERE clause.
445#
446do_test select4-7.1 {
447  execsql {
448    CREATE TABLE t2 AS SELECT log AS 'x', count(*) AS 'y' FROM t1 GROUP BY log;
449    SELECT * FROM t2 ORDER BY x;
450  }
451} {0 1 1 1 2 2 3 4 4 8 5 15}
452do_test select4-7.2 {
453  execsql2 {
454    SELECT * FROM t1 WHERE n IN (SELECT n FROM t1 INTERSECT SELECT x FROM t2)
455    ORDER BY n
456  }
457} {n 1 log 0 n 2 log 1 n 3 log 2 n 4 log 2 n 5 log 3}
458do_test select4-7.3 {
459  execsql2 {
460    SELECT * FROM t1 WHERE n IN (SELECT n FROM t1 EXCEPT SELECT x FROM t2)
461    ORDER BY n LIMIT 2
462  }
463} {n 6 log 3 n 7 log 3}
464do_test select4-7.4 {
465  execsql2 {
466    SELECT * FROM t1 WHERE n IN (SELECT n FROM t1 UNION SELECT x FROM t2)
467    ORDER BY n LIMIT 2
468  }
469} {n 1 log 0 n 2 log 1}
470
471# Make sure DISTINCT works appropriately on TEXT and NUMERIC columns.
472do_test select4-8.1 {
473  execsql {
474    BEGIN;
475    CREATE TABLE t3(a text, b float, c text);
476    INSERT INTO t3 VALUES(1, 1.1, '1.1');
477    INSERT INTO t3 VALUES(2, 1.10, '1.10');
478    INSERT INTO t3 VALUES(3, 1.10, '1.1');
479    INSERT INTO t3 VALUES(4, 1.1, '1.10');
480    INSERT INTO t3 VALUES(5, 1.2, '1.2');
481    INSERT INTO t3 VALUES(6, 1.3, '1.3');
482    COMMIT;
483  }
484  execsql {
485    SELECT DISTINCT b FROM t3 ORDER BY c;
486  }
487} {1.1 1.2 1.3}
488do_test select4-8.2 {
489  execsql {
490    SELECT DISTINCT c FROM t3 ORDER BY c;
491  }
492} {1.1 1.10 1.2 1.3}
493
494
495finish_test
496