xref: /sqlite-3.40.0/test/select4.test (revision 60f4e091)
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.30 2009/04/16 00:24:24 drh 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} {(1<<$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}
108
109# EVIDENCE-OF: R-02644-22131 In a compound SELECT statement, only the
110# last or right-most simple SELECT may have an ORDER BY clause.
111#
112do_test select4-1.3 {
113  set v [catch {execsql {
114    SELECT DISTINCT log FROM t1 ORDER BY log
115    UNION ALL
116    SELECT n FROM t1 WHERE log=3
117    ORDER BY log;
118  }} msg]
119  lappend v $msg
120} {1 {ORDER BY clause should come after UNION ALL not before}}
121do_catchsql_test select4-1.4 {
122  SELECT (VALUES(0) INTERSECT SELECT(0) UNION SELECT(0) ORDER BY 1 UNION
123          SELECT 0 UNION SELECT 0 ORDER BY 1);
124} {1 {ORDER BY clause should come after UNION not before}}
125
126# Union operator
127#
128do_test select4-2.1 {
129  execsql {
130    SELECT DISTINCT log FROM t1
131    UNION
132    SELECT n FROM t1 WHERE log=3
133    ORDER BY log;
134  }
135} {0 1 2 3 4 5 6 7 8}
136ifcapable subquery {
137  do_test select4-2.2 {
138    execsql {
139      SELECT log FROM t1 WHERE n IN
140        (SELECT DISTINCT log FROM t1 UNION
141         SELECT n FROM t1 WHERE log=3)
142      ORDER BY log;
143    }
144  } {0 1 2 2 3 3 3 3}
145}
146do_test select4-2.3 {
147  set v [catch {execsql {
148    SELECT DISTINCT log FROM t1 ORDER BY log
149    UNION
150    SELECT n FROM t1 WHERE log=3
151    ORDER BY log;
152  }} msg]
153  lappend v $msg
154} {1 {ORDER BY clause should come after UNION not before}}
155do_test select4-2.4 {
156  set v [catch {execsql {
157    SELECT 0 ORDER BY (SELECT 0) UNION SELECT 0;
158  }} msg]
159  lappend v $msg
160} {1 {ORDER BY clause should come after UNION not before}}
161
162# Except operator
163#
164do_test select4-3.1.1 {
165  execsql {
166    SELECT DISTINCT log FROM t1
167    EXCEPT
168    SELECT n FROM t1 WHERE log=3
169    ORDER BY log;
170  }
171} {0 1 2 3 4}
172do_test select4-3.1.2 {
173  execsql {
174    CREATE TABLE t2 AS
175      SELECT DISTINCT log FROM t1
176      EXCEPT
177      SELECT n FROM t1 WHERE log=3
178      ORDER BY log;
179    SELECT * FROM t2;
180  }
181} {0 1 2 3 4}
182execsql {DROP TABLE t2}
183do_test select4-3.1.3 {
184  execsql {
185    CREATE TABLE t2 AS
186      SELECT DISTINCT log FROM t1
187      EXCEPT
188      SELECT n FROM t1 WHERE log=3
189      ORDER BY log DESC;
190    SELECT * FROM t2;
191  }
192} {4 3 2 1 0}
193execsql {DROP TABLE t2}
194ifcapable subquery {
195  do_test select4-3.2 {
196    execsql {
197      SELECT log FROM t1 WHERE n IN
198        (SELECT DISTINCT log FROM t1 EXCEPT
199         SELECT n FROM t1 WHERE log=3)
200      ORDER BY log;
201    }
202  } {0 1 2 2}
203}
204do_test select4-3.3 {
205  set v [catch {execsql {
206    SELECT DISTINCT log FROM t1 ORDER BY log
207    EXCEPT
208    SELECT n FROM t1 WHERE log=3
209    ORDER BY log;
210  }} msg]
211  lappend v $msg
212} {1 {ORDER BY clause should come after EXCEPT not before}}
213
214# Intersect operator
215#
216do_test select4-4.1.1 {
217  execsql {
218    SELECT DISTINCT log FROM t1
219    INTERSECT
220    SELECT n FROM t1 WHERE log=3
221    ORDER BY log;
222  }
223} {5}
224
225do_test select4-4.1.2 {
226  execsql {
227    SELECT DISTINCT log FROM t1
228    UNION ALL
229    SELECT 6
230    INTERSECT
231    SELECT n FROM t1 WHERE log=3
232    ORDER BY t1.log;
233  }
234} {5 6}
235
236do_test select4-4.1.3 {
237  execsql {
238    CREATE TABLE t2 AS
239      SELECT DISTINCT log FROM t1 UNION ALL SELECT 6
240      INTERSECT
241      SELECT n FROM t1 WHERE log=3
242      ORDER BY log;
243    SELECT * FROM t2;
244  }
245} {5 6}
246execsql {DROP TABLE t2}
247do_test select4-4.1.4 {
248  execsql {
249    CREATE TABLE t2 AS
250      SELECT DISTINCT log FROM t1 UNION ALL SELECT 6
251      INTERSECT
252      SELECT n FROM t1 WHERE log=3
253      ORDER BY log DESC;
254    SELECT * FROM t2;
255  }
256} {6 5}
257execsql {DROP TABLE t2}
258ifcapable subquery {
259  do_test select4-4.2 {
260    execsql {
261      SELECT log FROM t1 WHERE n IN
262        (SELECT DISTINCT log FROM t1 INTERSECT
263         SELECT n FROM t1 WHERE log=3)
264      ORDER BY log;
265    }
266  } {3}
267}
268do_test select4-4.3 {
269  set v [catch {execsql {
270    SELECT DISTINCT log FROM t1 ORDER BY log
271    INTERSECT
272    SELECT n FROM t1 WHERE log=3
273    ORDER BY log;
274  }} msg]
275  lappend v $msg
276} {1 {ORDER BY clause should come after INTERSECT not before}}
277
278# Various error messages while processing UNION or INTERSECT
279#
280do_test select4-5.1 {
281  set v [catch {execsql {
282    SELECT DISTINCT log FROM t2
283    UNION ALL
284    SELECT n FROM t1 WHERE log=3
285    ORDER BY log;
286  }} msg]
287  lappend v $msg
288} {1 {no such table: t2}}
289do_test select4-5.2 {
290  set v [catch {execsql {
291    SELECT DISTINCT log AS "xyzzy" FROM t1
292    UNION ALL
293    SELECT n FROM t1 WHERE log=3
294    ORDER BY xyzzy;
295  }} msg]
296  lappend v $msg
297} {0 {0 1 2 3 4 5 5 6 7 8}}
298do_test select4-5.2b {
299  set v [catch {execsql {
300    SELECT DISTINCT log AS xyzzy FROM t1
301    UNION ALL
302    SELECT n FROM t1 WHERE log=3
303    ORDER BY "xyzzy";
304  }} msg]
305  lappend v $msg
306} {0 {0 1 2 3 4 5 5 6 7 8}}
307do_test select4-5.2c {
308  set v [catch {execsql {
309    SELECT DISTINCT log FROM t1
310    UNION ALL
311    SELECT n FROM t1 WHERE log=3
312    ORDER BY "xyzzy";
313  }} msg]
314  lappend v $msg
315} {1 {1st ORDER BY term does not match any column in the result set}}
316do_test select4-5.2d {
317  set v [catch {execsql {
318    SELECT DISTINCT log FROM t1
319    INTERSECT
320    SELECT n FROM t1 WHERE log=3
321    ORDER BY "xyzzy";
322  }} msg]
323  lappend v $msg
324} {1 {1st ORDER BY term does not match any column in the result set}}
325do_test select4-5.2e {
326  set v [catch {execsql {
327    SELECT DISTINCT log FROM t1
328    UNION ALL
329    SELECT n FROM t1 WHERE log=3
330    ORDER BY n;
331  }} msg]
332  lappend v $msg
333} {0 {0 1 2 3 4 5 5 6 7 8}}
334do_test select4-5.2f {
335  catchsql {
336    SELECT DISTINCT log FROM t1
337    UNION ALL
338    SELECT n FROM t1 WHERE log=3
339    ORDER BY log;
340  }
341} {0 {0 1 2 3 4 5 5 6 7 8}}
342do_test select4-5.2g {
343  catchsql {
344    SELECT DISTINCT log FROM t1
345    UNION ALL
346    SELECT n FROM t1 WHERE log=3
347    ORDER BY 1;
348  }
349} {0 {0 1 2 3 4 5 5 6 7 8}}
350do_test select4-5.2h {
351  catchsql {
352    SELECT DISTINCT log FROM t1
353    UNION ALL
354    SELECT n FROM t1 WHERE log=3
355    ORDER BY 2;
356  }
357} {1 {1st ORDER BY term out of range - should be between 1 and 1}}
358do_test select4-5.2i {
359  catchsql {
360    SELECT DISTINCT 1, log FROM t1
361    UNION ALL
362    SELECT 2, n FROM t1 WHERE log=3
363    ORDER BY 2, 1;
364  }
365} {0 {1 0 1 1 1 2 1 3 1 4 1 5 2 5 2 6 2 7 2 8}}
366do_test select4-5.2j {
367  catchsql {
368    SELECT DISTINCT 1, log FROM t1
369    UNION ALL
370    SELECT 2, n FROM t1 WHERE log=3
371    ORDER BY 1, 2 DESC;
372  }
373} {0 {1 5 1 4 1 3 1 2 1 1 1 0 2 8 2 7 2 6 2 5}}
374do_test select4-5.2k {
375  catchsql {
376    SELECT DISTINCT 1, log FROM t1
377    UNION ALL
378    SELECT 2, n FROM t1 WHERE log=3
379    ORDER BY n, 1;
380  }
381} {0 {1 0 1 1 1 2 1 3 1 4 1 5 2 5 2 6 2 7 2 8}}
382do_test select4-5.3 {
383  set v [catch {execsql {
384    SELECT DISTINCT log, n FROM t1
385    UNION ALL
386    SELECT n FROM t1 WHERE log=3
387    ORDER BY log;
388  }} msg]
389  lappend v $msg
390} {1 {SELECTs to the left and right of UNION ALL do not have the same number of result columns}}
391do_test select4-5.3-3807-1 {
392  catchsql {
393    SELECT 1 UNION SELECT 2, 3 UNION SELECT 4, 5 ORDER BY 1;
394  }
395} {1 {SELECTs to the left and right of UNION do not have the same number of result columns}}
396do_test select4-5.4 {
397  set v [catch {execsql {
398    SELECT log FROM t1 WHERE n=2
399    UNION ALL
400    SELECT log FROM t1 WHERE n=3
401    UNION ALL
402    SELECT log FROM t1 WHERE n=4
403    UNION ALL
404    SELECT log FROM t1 WHERE n=5
405    ORDER BY log;
406  }} msg]
407  lappend v $msg
408} {0 {1 2 2 3}}
409
410do_test select4-6.1 {
411  execsql {
412    SELECT log, count(*) as cnt FROM t1 GROUP BY log
413    UNION
414    SELECT log, n FROM t1 WHERE n=7
415    ORDER BY cnt, log;
416  }
417} {0 1 1 1 2 2 3 4 3 7 4 8 5 15}
418do_test select4-6.2 {
419  execsql {
420    SELECT log, count(*) FROM t1 GROUP BY log
421    UNION
422    SELECT log, n FROM t1 WHERE n=7
423    ORDER BY count(*), log;
424  }
425} {0 1 1 1 2 2 3 4 3 7 4 8 5 15}
426
427# NULLs are indistinct for the UNION operator.
428# Make sure the UNION operator recognizes this
429#
430do_test select4-6.3 {
431  execsql {
432    SELECT NULL UNION SELECT NULL UNION
433    SELECT 1 UNION SELECT 2 AS 'x'
434    ORDER BY x;
435  }
436} {{} 1 2}
437do_test select4-6.3.1 {
438  execsql {
439    SELECT NULL UNION ALL SELECT NULL UNION ALL
440    SELECT 1 UNION ALL SELECT 2 AS 'x'
441    ORDER BY x;
442  }
443} {{} {} 1 2}
444
445# Make sure the DISTINCT keyword treats NULLs as indistinct.
446#
447ifcapable subquery {
448  do_test select4-6.4 {
449    execsql {
450      SELECT * FROM (
451         SELECT NULL, 1 UNION ALL SELECT NULL, 1
452      );
453    }
454  } {{} 1 {} 1}
455  do_test select4-6.5 {
456    execsql {
457      SELECT DISTINCT * FROM (
458         SELECT NULL, 1 UNION ALL SELECT NULL, 1
459      );
460    }
461  } {{} 1}
462  do_test select4-6.6 {
463    execsql {
464      SELECT DISTINCT * FROM (
465         SELECT 1,2  UNION ALL SELECT 1,2
466      );
467    }
468  } {1 2}
469}
470
471# Test distinctness of NULL in other ways.
472#
473do_test select4-6.7 {
474  execsql {
475    SELECT NULL EXCEPT SELECT NULL
476  }
477} {}
478
479
480# Make sure column names are correct when a compound select appears as
481# an expression in the WHERE clause.
482#
483do_test select4-7.1 {
484  execsql {
485    CREATE TABLE t2 AS SELECT log AS 'x', count(*) AS 'y' FROM t1 GROUP BY log;
486    SELECT * FROM t2 ORDER BY x;
487  }
488} {0 1 1 1 2 2 3 4 4 8 5 15}
489ifcapable subquery {
490  do_test select4-7.2 {
491    execsql2 {
492      SELECT * FROM t1 WHERE n IN (SELECT n FROM t1 INTERSECT SELECT x FROM t2)
493      ORDER BY n
494    }
495  } {n 1 log 0 n 2 log 1 n 3 log 2 n 4 log 2 n 5 log 3}
496  do_test select4-7.3 {
497    execsql2 {
498      SELECT * FROM t1 WHERE n IN (SELECT n FROM t1 EXCEPT SELECT x FROM t2)
499      ORDER BY n LIMIT 2
500    }
501  } {n 6 log 3 n 7 log 3}
502  do_test select4-7.4 {
503    execsql2 {
504      SELECT * FROM t1 WHERE n IN (SELECT n FROM t1 UNION SELECT x FROM t2)
505      ORDER BY n LIMIT 2
506    }
507  } {n 1 log 0 n 2 log 1}
508} ;# ifcapable subquery
509
510} ;# ifcapable compound
511
512# Make sure DISTINCT works appropriately on TEXT and NUMERIC columns.
513do_test select4-8.1 {
514  execsql {
515    BEGIN;
516    CREATE TABLE t3(a text, b float, c text);
517    INSERT INTO t3 VALUES(1, 1.1, '1.1');
518    INSERT INTO t3 VALUES(2, 1.10, '1.10');
519    INSERT INTO t3 VALUES(3, 1.10, '1.1');
520    INSERT INTO t3 VALUES(4, 1.1, '1.10');
521    INSERT INTO t3 VALUES(5, 1.2, '1.2');
522    INSERT INTO t3 VALUES(6, 1.3, '1.3');
523    COMMIT;
524  }
525  execsql {
526    SELECT DISTINCT b FROM t3 ORDER BY c;
527  }
528} {1.1 1.2 1.3}
529do_test select4-8.2 {
530  execsql {
531    SELECT DISTINCT c FROM t3 ORDER BY c;
532  }
533} {1.1 1.10 1.2 1.3}
534
535# Make sure the names of columns are taken from the right-most subquery
536# right in a compound query.  Ticket #1721
537#
538ifcapable compound {
539
540do_test select4-9.1 {
541  execsql2 {
542    SELECT x, y FROM t2 UNION SELECT a, b FROM t3 ORDER BY x LIMIT 1
543  }
544} {x 0 y 1}
545do_test select4-9.2 {
546  execsql2 {
547    SELECT x, y FROM t2 UNION ALL SELECT a, b FROM t3 ORDER BY x LIMIT 1
548  }
549} {x 0 y 1}
550do_test select4-9.3 {
551  execsql2 {
552    SELECT x, y FROM t2 EXCEPT SELECT a, b FROM t3 ORDER BY x LIMIT 1
553  }
554} {x 0 y 1}
555do_test select4-9.4 {
556  execsql2 {
557    SELECT x, y FROM t2 INTERSECT SELECT 0 AS a, 1 AS b;
558  }
559} {x 0 y 1}
560do_test select4-9.5 {
561  execsql2 {
562    SELECT 0 AS x, 1 AS y
563    UNION
564    SELECT 2 AS p, 3 AS q
565    UNION
566    SELECT 4 AS a, 5 AS b
567    ORDER BY x LIMIT 1
568  }
569} {x 0 y 1}
570
571ifcapable subquery {
572do_test select4-9.6 {
573  execsql2 {
574    SELECT * FROM (
575      SELECT 0 AS x, 1 AS y
576      UNION
577      SELECT 2 AS p, 3 AS q
578      UNION
579      SELECT 4 AS a, 5 AS b
580    ) ORDER BY 1 LIMIT 1;
581  }
582} {x 0 y 1}
583do_test select4-9.7 {
584  execsql2 {
585    SELECT * FROM (
586      SELECT 0 AS x, 1 AS y
587      UNION
588      SELECT 2 AS p, 3 AS q
589      UNION
590      SELECT 4 AS a, 5 AS b
591    ) ORDER BY x LIMIT 1;
592  }
593} {x 0 y 1}
594} ;# ifcapable subquery
595
596do_test select4-9.8 {
597  execsql {
598    SELECT 0 AS x, 1 AS y
599    UNION
600    SELECT 2 AS y, -3 AS x
601    ORDER BY x LIMIT 1;
602  }
603} {0 1}
604
605do_test select4-9.9.1 {
606  execsql2 {
607    SELECT 1 AS a, 2 AS b UNION ALL SELECT 3 AS b, 4 AS a
608  }
609} {a 1 b 2 a 3 b 4}
610
611ifcapable subquery {
612do_test select4-9.9.2 {
613  execsql2 {
614    SELECT * FROM (SELECT 1 AS a, 2 AS b UNION ALL SELECT 3 AS b, 4 AS a)
615     WHERE b=3
616  }
617} {}
618do_test select4-9.10 {
619  execsql2 {
620    SELECT * FROM (SELECT 1 AS a, 2 AS b UNION ALL SELECT 3 AS b, 4 AS a)
621     WHERE b=2
622  }
623} {a 1 b 2}
624do_test select4-9.11 {
625  execsql2 {
626    SELECT * FROM (SELECT 1 AS a, 2 AS b UNION ALL SELECT 3 AS e, 4 AS b)
627     WHERE b=2
628  }
629} {a 1 b 2}
630do_test select4-9.12 {
631  execsql2 {
632    SELECT * FROM (SELECT 1 AS a, 2 AS b UNION ALL SELECT 3 AS e, 4 AS b)
633     WHERE b>0
634  }
635} {a 1 b 2 a 3 b 4}
636} ;# ifcapable subquery
637
638# Try combining DISTINCT, LIMIT, and OFFSET.  Make sure they all work
639# together.
640#
641do_test select4-10.1 {
642  execsql {
643    SELECT DISTINCT log FROM t1 ORDER BY log
644  }
645} {0 1 2 3 4 5}
646do_test select4-10.2 {
647  execsql {
648    SELECT DISTINCT log FROM t1 ORDER BY log LIMIT 4
649  }
650} {0 1 2 3}
651do_test select4-10.3 {
652  execsql {
653    SELECT DISTINCT log FROM t1 ORDER BY log LIMIT 0
654  }
655} {}
656do_test select4-10.4 {
657  execsql {
658    SELECT DISTINCT log FROM t1 ORDER BY log LIMIT -1
659  }
660} {0 1 2 3 4 5}
661do_test select4-10.5 {
662  execsql {
663    SELECT DISTINCT log FROM t1 ORDER BY log LIMIT -1 OFFSET 2
664  }
665} {2 3 4 5}
666do_test select4-10.6 {
667  execsql {
668    SELECT DISTINCT log FROM t1 ORDER BY log LIMIT 3 OFFSET 2
669  }
670} {2 3 4}
671do_test select4-10.7 {
672  execsql {
673    SELECT DISTINCT log FROM t1 ORDER BY +log LIMIT 3 OFFSET 20
674  }
675} {}
676do_test select4-10.8 {
677  execsql {
678    SELECT DISTINCT log FROM t1 ORDER BY log LIMIT 0 OFFSET 3
679  }
680} {}
681do_test select4-10.9 {
682  execsql {
683    SELECT DISTINCT max(n), log FROM t1 ORDER BY +log; -- LIMIT 2 OFFSET 1
684  }
685} {31 5}
686
687# Make sure compound SELECTs with wildly different numbers of columns
688# do not cause assertion faults due to register allocation issues.
689#
690do_test select4-11.1 {
691  catchsql {
692    SELECT x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x FROM t2
693    UNION
694    SELECT x FROM t2
695  }
696} {1 {SELECTs to the left and right of UNION do not have the same number of result columns}}
697do_test select4-11.2 {
698  catchsql {
699    SELECT x FROM t2
700    UNION
701    SELECT x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x FROM t2
702  }
703} {1 {SELECTs to the left and right of UNION do not have the same number of result columns}}
704do_test select4-11.3 {
705  catchsql {
706    SELECT x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x FROM t2
707    UNION ALL
708    SELECT x FROM t2
709  }
710} {1 {SELECTs to the left and right of UNION ALL do not have the same number of result columns}}
711do_test select4-11.4 {
712  catchsql {
713    SELECT x FROM t2
714    UNION ALL
715    SELECT x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x FROM t2
716  }
717} {1 {SELECTs to the left and right of UNION ALL do not have the same number of result columns}}
718do_test select4-11.5 {
719  catchsql {
720    SELECT x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x FROM t2
721    EXCEPT
722    SELECT x FROM t2
723  }
724} {1 {SELECTs to the left and right of EXCEPT do not have the same number of result columns}}
725do_test select4-11.6 {
726  catchsql {
727    SELECT x FROM t2
728    EXCEPT
729    SELECT x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x FROM t2
730  }
731} {1 {SELECTs to the left and right of EXCEPT do not have the same number of result columns}}
732do_test select4-11.7 {
733  catchsql {
734    SELECT x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x FROM t2
735    INTERSECT
736    SELECT x FROM t2
737  }
738} {1 {SELECTs to the left and right of INTERSECT do not have the same number of result columns}}
739do_test select4-11.8 {
740  catchsql {
741    SELECT x FROM t2
742    INTERSECT
743    SELECT x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x FROM t2
744  }
745} {1 {SELECTs to the left and right of INTERSECT do not have the same number of result columns}}
746
747do_test select4-11.11 {
748  catchsql {
749    SELECT x FROM t2
750    UNION
751    SELECT x FROM t2
752    UNION ALL
753    SELECT x FROM t2
754    EXCEPT
755    SELECT x FROM t2
756    INTERSECT
757    SELECT x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x FROM t2
758  }
759} {1 {SELECTs to the left and right of INTERSECT do not have the same number of result columns}}
760do_test select4-11.12 {
761  catchsql {
762    SELECT x FROM t2
763    UNION
764    SELECT x FROM t2
765    UNION ALL
766    SELECT x FROM t2
767    EXCEPT
768    SELECT x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x FROM t2
769    EXCEPT
770    SELECT x FROM t2
771  }
772} {1 {SELECTs to the left and right of EXCEPT do not have the same number of result columns}}
773do_test select4-11.13 {
774  catchsql {
775    SELECT x FROM t2
776    UNION
777    SELECT x FROM t2
778    UNION ALL
779    SELECT x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x FROM t2
780    UNION ALL
781    SELECT x FROM t2
782    EXCEPT
783    SELECT x FROM t2
784  }
785} {1 {SELECTs to the left and right of UNION ALL do not have the same number of result columns}}
786do_test select4-11.14 {
787  catchsql {
788    SELECT x FROM t2
789    UNION
790    SELECT x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x FROM t2
791    UNION
792    SELECT x FROM t2
793    UNION ALL
794    SELECT x FROM t2
795    EXCEPT
796    SELECT x FROM t2
797  }
798} {1 {SELECTs to the left and right of UNION do not have the same number of result columns}}
799do_test select4-11.15 {
800  catchsql {
801    SELECT x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x FROM t2
802    UNION
803    SELECT x FROM t2
804    INTERSECT
805    SELECT x FROM t2
806    UNION ALL
807    SELECT x FROM t2
808    EXCEPT
809    SELECT x FROM t2
810  }
811} {1 {SELECTs to the left and right of UNION do not have the same number of result columns}}
812do_test select4-11.16 {
813  catchsql {
814    INSERT INTO t2(rowid) VALUES(2) UNION SELECT 3,4 UNION SELECT 5,6 ORDER BY 1;
815  }
816} {1 {SELECTs to the left and right of UNION do not have the same number of result columns}}
817
818do_test select4-12.1 {
819  sqlite3 db2 :memory:
820  catchsql {
821    SELECT 1 UNION SELECT 2,3 UNION SELECT 4,5 ORDER BY 1;
822  } db2
823} {1 {SELECTs to the left and right of UNION do not have the same number of result columns}}
824
825} ;# ifcapable compound
826
827
828# Ticket [3557ad65a076c] - Incorrect DISTINCT processing with an
829# indexed query using IN.
830#
831do_test select4-13.1 {
832  sqlite3 db test.db
833  db eval {
834    CREATE TABLE t13(a,b);
835    INSERT INTO t13 VALUES(1,1);
836    INSERT INTO t13 VALUES(2,1);
837    INSERT INTO t13 VALUES(3,1);
838    INSERT INTO t13 VALUES(2,2);
839    INSERT INTO t13 VALUES(3,2);
840    INSERT INTO t13 VALUES(4,2);
841    CREATE INDEX t13ab ON t13(a,b);
842    SELECT DISTINCT b from t13 WHERE a IN (1,2,3);
843  }
844} {1 2}
845
846# 2014-02-18: Make sure compound SELECTs work with VALUES clauses
847#
848do_execsql_test select4-14.1 {
849  CREATE TABLE t14(a,b,c);
850  INSERT INTO t14 VALUES(1,2,3),(4,5,6);
851  SELECT * FROM t14 INTERSECT VALUES(3,2,1),(2,3,1),(1,2,3),(2,1,3);
852} {1 2 3}
853do_execsql_test select4-14.2 {
854  SELECT * FROM t14 INTERSECT VALUES(1,2,3);
855} {1 2 3}
856do_execsql_test select4-14.3 {
857  SELECT * FROM t14
858   UNION VALUES(3,2,1),(2,3,1),(1,2,3),(7,8,9),(4,5,6)
859   UNION SELECT * FROM t14 ORDER BY 1, 2, 3
860} {1 2 3 2 3 1 3 2 1 4 5 6 7 8 9}
861do_execsql_test select4-14.4 {
862  SELECT * FROM t14
863   UNION VALUES(3,2,1)
864   UNION SELECT * FROM t14 ORDER BY 1, 2, 3
865} {1 2 3 3 2 1 4 5 6}
866do_execsql_test select4-14.5 {
867  SELECT * FROM t14 EXCEPT VALUES(3,2,1),(2,3,1),(1,2,3),(2,1,3);
868} {4 5 6}
869do_execsql_test select4-14.6 {
870  SELECT * FROM t14 EXCEPT VALUES(1,2,3)
871} {4 5 6}
872do_execsql_test select4-14.7 {
873  SELECT * FROM t14 EXCEPT VALUES(1,2,3) EXCEPT VALUES(4,5,6)
874} {}
875do_execsql_test select4-14.8 {
876  SELECT * FROM t14 EXCEPT VALUES('a','b','c') EXCEPT VALUES(4,5,6)
877} {1 2 3}
878do_execsql_test select4-14.9 {
879  SELECT * FROM t14 UNION ALL VALUES(3,2,1),(2,3,1),(1,2,3),(2,1,3);
880} {1 2 3 4 5 6 3 2 1 2 3 1 1 2 3 2 1 3}
881do_execsql_test select4-14.10 {
882  SELECT (VALUES(1),(2),(3),(4))
883} {1}
884do_execsql_test select4-14.11 {
885  SELECT (SELECT 1 UNION ALL SELECT 2 UNION ALL SELECT 3 UNION ALL SELECT 4)
886} {1}
887do_execsql_test select4-14.12 {
888  VALUES(1) UNION VALUES(2);
889} {1 2}
890do_execsql_test select4-14.13 {
891  VALUES(1),(2),(3) EXCEPT VALUES(2);
892} {1 3}
893do_execsql_test select4-14.14 {
894  VALUES(1),(2),(3) EXCEPT VALUES(1),(3);
895} {2}
896do_execsql_test select4-14.15 {
897  SELECT * FROM (SELECT 123), (SELECT 456) ON likely(0 OR 1) OR 0;
898} {123 456}
899
900finish_test
901