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