123456789101112131415161718192021222324252627282930313233343536373839404142434445464748495051525354555657585960616263646566676869707172737475767778798081828384858687888990919293949596979899100101102103104105106107108109110111112113114115116117118119120121122123124125126127128129130131132133134135136137138139140141142143144145146147148149150151152153154155156157158159160161162163164165166167168169170171172173174175176177178179180181182183184185186187188189190191192193194195196197198199200201202203204205206207208209210211212213214215216217218219220221222223224225226227228229230231232233234235236237238239240241242243244245246247248249250251252253254255256257258259260261262263264265266267268269270271272273274275276277278279280281282283284285286287288289290291292293294295296297298299300301302303304305306307308309310311312313314315316317318319320321322323324325326327328329330331332333334335336337338339340341342343344345346347348349350351352353354355356357358359360361362363364365366367368369370371372373374375376377378379380 |
- # 2001 September 15
- #
- # The author disclaims copyright to this source code. In place of
- # a legal notice, here is a blessing:
- #
- # May you do good and not evil.
- # May you find forgiveness for yourself and forgive others.
- # May you share freely, never taking more than you give.
- #
- #***********************************************************************
- # This file implements regression tests for SQLite library. The
- # focus of this file is testing UNION, INTERSECT and EXCEPT operators
- # in SELECT statements.
- #
- # $Id: select4.test,v 1.10 2002/06/02 16:09:03 drh Exp $
- set testdir [file dirname $argv0]
- source $testdir/tester.tcl
- # Build some test data
- #
- set fd [open data1.txt w]
- for {set i 1} {$i<32} {incr i} {
- for {set j 0} {pow(2,$j)<$i} {incr j} {}
- puts $fd "$i\t$j"
- }
- close $fd
- execsql {
- CREATE TABLE t1(n int, log int);
- COPY t1 FROM 'data1.txt'
- }
- file delete data1.txt
- do_test select4-1.0 {
- execsql {SELECT DISTINCT log FROM t1 ORDER BY log}
- } {0 1 2 3 4 5}
- # Union All operator
- #
- do_test select4-1.1a {
- lsort [execsql {SELECT DISTINCT log FROM t1}]
- } {0 1 2 3 4 5}
- do_test select4-1.1b {
- lsort [execsql {SELECT n FROM t1 WHERE log=3}]
- } {5 6 7 8}
- do_test select4-1.1c {
- execsql {
- SELECT DISTINCT log FROM t1
- UNION ALL
- SELECT n FROM t1 WHERE log=3
- ORDER BY log;
- }
- } {0 1 2 3 4 5 5 6 7 8}
- do_test select4-1.2 {
- execsql {
- SELECT log FROM t1 WHERE n IN
- (SELECT DISTINCT log FROM t1 UNION ALL
- SELECT n FROM t1 WHERE log=3)
- ORDER BY log;
- }
- } {0 1 2 2 3 3 3 3}
- do_test select4-1.3 {
- set v [catch {execsql {
- SELECT DISTINCT log FROM t1 ORDER BY log
- UNION ALL
- SELECT n FROM t1 WHERE log=3
- ORDER BY log;
- }} msg]
- lappend v $msg
- } {1 {ORDER BY clause should come after UNION ALL not before}}
- # Union operator
- #
- do_test select4-2.1 {
- execsql {
- SELECT DISTINCT log FROM t1
- UNION
- SELECT n FROM t1 WHERE log=3
- ORDER BY log;
- }
- } {0 1 2 3 4 5 6 7 8}
- do_test select4-2.2 {
- execsql {
- SELECT log FROM t1 WHERE n IN
- (SELECT DISTINCT log FROM t1 UNION
- SELECT n FROM t1 WHERE log=3)
- ORDER BY log;
- }
- } {0 1 2 2 3 3 3 3}
- do_test select4-2.3 {
- set v [catch {execsql {
- SELECT DISTINCT log FROM t1 ORDER BY log
- UNION
- SELECT n FROM t1 WHERE log=3
- ORDER BY log;
- }} msg]
- lappend v $msg
- } {1 {ORDER BY clause should come after UNION not before}}
- # Except operator
- #
- do_test select4-3.1 {
- execsql {
- SELECT DISTINCT log FROM t1
- EXCEPT
- SELECT n FROM t1 WHERE log=3
- ORDER BY log;
- }
- } {0 1 2 3 4}
- do_test select4-3.2 {
- execsql {
- SELECT log FROM t1 WHERE n IN
- (SELECT DISTINCT log FROM t1 EXCEPT
- SELECT n FROM t1 WHERE log=3)
- ORDER BY log;
- }
- } {0 1 2 2}
- do_test select4-3.3 {
- set v [catch {execsql {
- SELECT DISTINCT log FROM t1 ORDER BY log
- EXCEPT
- SELECT n FROM t1 WHERE log=3
- ORDER BY log;
- }} msg]
- lappend v $msg
- } {1 {ORDER BY clause should come after EXCEPT not before}}
- # Intersect operator
- #
- do_test select4-4.1 {
- execsql {
- SELECT DISTINCT log FROM t1
- INTERSECT
- SELECT n FROM t1 WHERE log=3
- ORDER BY log;
- }
- } {5}
- do_test select4-4.2 {
- execsql {
- SELECT log FROM t1 WHERE n IN
- (SELECT DISTINCT log FROM t1 INTERSECT
- SELECT n FROM t1 WHERE log=3)
- ORDER BY log;
- }
- } {3}
- do_test select4-4.3 {
- set v [catch {execsql {
- SELECT DISTINCT log FROM t1 ORDER BY log
- INTERSECT
- SELECT n FROM t1 WHERE log=3
- ORDER BY log;
- }} msg]
- lappend v $msg
- } {1 {ORDER BY clause should come after INTERSECT not before}}
- # Various error messages while processing UNION or INTERSECT
- #
- do_test select4-5.1 {
- set v [catch {execsql {
- SELECT DISTINCT log FROM t2
- UNION ALL
- SELECT n FROM t1 WHERE log=3
- ORDER BY log;
- }} msg]
- lappend v $msg
- } {1 {no such table: t2}}
- do_test select4-5.2 {
- set v [catch {execsql {
- SELECT DISTINCT log AS "xyzzy" FROM t1
- UNION ALL
- SELECT n FROM t1 WHERE log=3
- ORDER BY xyzzy;
- }} msg]
- lappend v $msg
- } {0 {0 1 2 3 4 5 5 6 7 8}}
- do_test select4-5.2b {
- set v [catch {execsql {
- SELECT DISTINCT log AS xyzzy FROM t1
- UNION ALL
- SELECT n FROM t1 WHERE log=3
- ORDER BY 'xyzzy';
- }} msg]
- lappend v $msg
- } {0 {0 1 2 3 4 5 5 6 7 8}}
- do_test select4-5.2c {
- set v [catch {execsql {
- SELECT DISTINCT log FROM t1
- UNION ALL
- SELECT n FROM t1 WHERE log=3
- ORDER BY 'xyzzy';
- }} msg]
- lappend v $msg
- } {1 {ORDER BY term number 1 does not match any result column}}
- do_test select4-5.2d {
- set v [catch {execsql {
- SELECT DISTINCT log FROM t1
- INTERSECT
- SELECT n FROM t1 WHERE log=3
- ORDER BY 'xyzzy';
- }} msg]
- lappend v $msg
- } {1 {ORDER BY term number 1 does not match any result column}}
- do_test select4-5.2e {
- set v [catch {execsql {
- SELECT DISTINCT log FROM t1
- UNION ALL
- SELECT n FROM t1 WHERE log=3
- ORDER BY n;
- }} msg]
- lappend v $msg
- } {0 {0 1 2 3 4 5 5 6 7 8}}
- do_test select4-5.2f {
- catchsql {
- SELECT DISTINCT log FROM t1
- UNION ALL
- SELECT n FROM t1 WHERE log=3
- ORDER BY log;
- }
- } {0 {0 1 2 3 4 5 5 6 7 8}}
- do_test select4-5.2g {
- catchsql {
- SELECT DISTINCT log FROM t1
- UNION ALL
- SELECT n FROM t1 WHERE log=3
- ORDER BY 1;
- }
- } {0 {0 1 2 3 4 5 5 6 7 8}}
- do_test select4-5.2h {
- catchsql {
- SELECT DISTINCT log FROM t1
- UNION ALL
- SELECT n FROM t1 WHERE log=3
- ORDER BY 2;
- }
- } {1 {ORDER BY position 2 should be between 1 and 1}}
- do_test select4-5.2i {
- catchsql {
- SELECT DISTINCT 1, log FROM t1
- UNION ALL
- SELECT 2, n FROM t1 WHERE log=3
- ORDER BY 2, 1;
- }
- } {0 {1 0 1 1 1 2 1 3 1 4 1 5 2 5 2 6 2 7 2 8}}
- do_test select4-5.2j {
- catchsql {
- SELECT DISTINCT 1, log FROM t1
- UNION ALL
- SELECT 2, n FROM t1 WHERE log=3
- ORDER BY 1, 2 DESC;
- }
- } {0 {1 5 1 4 1 3 1 2 1 1 1 0 2 8 2 7 2 6 2 5}}
- do_test select4-5.2k {
- catchsql {
- SELECT DISTINCT 1, log FROM t1
- UNION ALL
- SELECT 2, n FROM t1 WHERE log=3
- ORDER BY n, 1;
- }
- } {0 {1 0 1 1 1 2 1 3 1 4 1 5 2 5 2 6 2 7 2 8}}
- do_test select4-5.3 {
- set v [catch {execsql {
- SELECT DISTINCT log, n FROM t1
- UNION ALL
- SELECT n FROM t1 WHERE log=3
- ORDER BY log;
- }} msg]
- lappend v $msg
- } {1 {SELECTs to the left and right of UNION ALL do not have the same number of result columns}}
- do_test select4-5.4 {
- set v [catch {execsql {
- SELECT log FROM t1 WHERE n=2
- UNION ALL
- SELECT log FROM t1 WHERE n=3
- UNION ALL
- SELECT log FROM t1 WHERE n=4
- UNION ALL
- SELECT log FROM t1 WHERE n=5
- ORDER BY log;
- }} msg]
- lappend v $msg
- } {0 {1 2 2 3}}
- do_test select4-6.1 {
- execsql {
- SELECT log, count(*) as cnt FROM t1 GROUP BY log
- UNION
- SELECT log, n FROM t1 WHERE n=7
- ORDER BY cnt, log;
- }
- } {0 1 1 1 2 2 3 4 3 7 4 8 5 15}
- do_test select4-6.2 {
- execsql {
- SELECT log, count(*) FROM t1 GROUP BY log
- UNION
- SELECT log, n FROM t1 WHERE n=7
- ORDER BY count(*), log;
- }
- } {0 1 1 1 2 2 3 4 3 7 4 8 5 15}
- # NULLs are indistinct for the UNION operator.
- # Make sure the UNION operator recognizes this
- #
- do_test select4-6.3 {
- execsql {
- SELECT NULL UNION SELECT NULL UNION
- SELECT 1 UNION SELECT 2 AS 'x'
- ORDER BY x;
- }
- } {{} 1 2}
- do_test select4-6.3.1 {
- execsql {
- SELECT NULL UNION ALL SELECT NULL UNION ALL
- SELECT 1 UNION ALL SELECT 2 AS 'x'
- ORDER BY x;
- }
- } {{} {} 1 2}
- # Make sure the DISTINCT keyword treats NULLs as indistinct.
- #
- do_test select4-6.4 {
- execsql {
- SELECT * FROM (
- SELECT NULL, 1 UNION ALL SELECT NULL, 1
- );
- }
- } {{} 1 {} 1}
- do_test select4-6.5 {
- execsql {
- SELECT DISTINCT * FROM (
- SELECT NULL, 1 UNION ALL SELECT NULL, 1
- );
- }
- } {{} 1}
- do_test select4-6.6 {
- execsql {
- SELECT DISTINCT * FROM (
- SELECT 1,2 UNION ALL SELECT 1,2
- );
- }
- } {1 2}
- # Test distinctness of NULL in other ways.
- #
- do_test select4-6.7 {
- execsql {
- SELECT NULL EXCEPT SELECT NULL
- }
- } {}
- # Make sure column names are correct when a compound select appears as
- # an expression in the WHERE clause.
- #
- do_test select4-7.1 {
- execsql {
- CREATE TABLE t2 AS SELECT log AS 'x', count(*) AS 'y' FROM t1 GROUP BY log;
- SELECT * FROM t2 ORDER BY x;
- }
- } {0 1 1 1 2 2 3 4 4 8 5 15}
- do_test select4-7.2 {
- execsql2 {
- SELECT * FROM t1 WHERE n IN (SELECT n FROM t1 INTERSECT SELECT x FROM t2)
- ORDER BY n
- }
- } {n 1 log 0 n 2 log 1 n 3 log 2 n 4 log 2 n 5 log 3}
- do_test select4-7.3 {
- execsql2 {
- SELECT * FROM t1 WHERE n IN (SELECT n FROM t1 EXCEPT SELECT x FROM t2)
- ORDER BY n LIMIT 2
- }
- } {n 6 log 3 n 7 log 3}
- do_test select4-7.4 {
- execsql2 {
- SELECT * FROM t1 WHERE n IN (SELECT n FROM t1 UNION SELECT x FROM t2)
- ORDER BY n LIMIT 2
- }
- } {n 1 log 0 n 2 log 1}
- finish_test
|