2001-09-16 04:13:26 +04:00
|
|
|
# 2001 September 15
|
2000-06-08 04:28:51 +04:00
|
|
|
#
|
2001-09-16 04:13:26 +04:00
|
|
|
# The author disclaims copyright to this source code. In place of
|
|
|
|
# a legal notice, here is a blessing:
|
2000-06-08 04:28:51 +04:00
|
|
|
#
|
2001-09-16 04:13:26 +04:00
|
|
|
# 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.
|
2000-06-08 04:28:51 +04:00
|
|
|
#
|
|
|
|
#***********************************************************************
|
|
|
|
# This file implements regression tests for SQLite library. The
|
|
|
|
# focus of this file is testing UNION, INTERSECT and EXCEPT operators
|
|
|
|
# in SELECT statements.
|
|
|
|
#
|
2002-05-24 20:14:15 +04:00
|
|
|
# $Id: select4.test,v 1.6 2002/05/24 16:14:16 drh Exp $
|
2000-06-08 04:28:51 +04:00
|
|
|
|
|
|
|
set testdir [file dirname $argv0]
|
|
|
|
source $testdir/tester.tcl
|
|
|
|
|
|
|
|
# Build some test data
|
|
|
|
#
|
2000-06-08 05:55:29 +04:00
|
|
|
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
|
|
|
|
|
2000-06-08 04:28:51 +04:00
|
|
|
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}
|
2000-06-08 05:55:29 +04:00
|
|
|
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}}
|
2000-06-08 04:28:51 +04:00
|
|
|
|
|
|
|
# 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}
|
2000-06-08 05:55:29 +04:00
|
|
|
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}}
|
2000-06-08 04:28:51 +04:00
|
|
|
|
|
|
|
# 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}
|
2000-06-08 05:55:29 +04:00
|
|
|
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}}
|
2000-06-08 04:28:51 +04:00
|
|
|
|
|
|
|
# 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}
|
2000-06-08 05:55:29 +04:00
|
|
|
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 {
|
2002-05-24 20:14:15 +04:00
|
|
|
SELECT DISTINCT log AS xyzzy FROM t1
|
2000-06-08 05:55:29 +04:00
|
|
|
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.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}}
|
2000-06-08 04:28:51 +04:00
|
|
|
|
2000-06-08 19:10:46 +04:00
|
|
|
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}
|
|
|
|
|
2002-04-23 21:10:18 +04:00
|
|
|
# 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}
|
|
|
|
|
|
|
|
|
2000-06-08 04:28:51 +04:00
|
|
|
finish_test
|