xref: /illumos-gate/usr/src/lib/libsqlite/test/subselect.test (revision 1da57d551424de5a9d469760be7c4b4d4f10a755)
1*1da57d55SToomas Soome#
2c5c4113dSnw141292# 2001 September 15
3c5c4113dSnw141292#
4c5c4113dSnw141292# The author disclaims copyright to this source code.  In place of
5c5c4113dSnw141292# a legal notice, here is a blessing:
6c5c4113dSnw141292#
7c5c4113dSnw141292#    May you do good and not evil.
8c5c4113dSnw141292#    May you find forgiveness for yourself and forgive others.
9c5c4113dSnw141292#    May you share freely, never taking more than you give.
10c5c4113dSnw141292#
11c5c4113dSnw141292#***********************************************************************
12c5c4113dSnw141292# This file implements regression tests for SQLite library.  The
13c5c4113dSnw141292# focus of this file is testing SELECT statements that are part of
14c5c4113dSnw141292# expressions.
15c5c4113dSnw141292#
16c5c4113dSnw141292# $Id: subselect.test,v 1.7 2002/07/15 18:55:26 drh Exp $
17c5c4113dSnw141292
18c5c4113dSnw141292set testdir [file dirname $argv0]
19c5c4113dSnw141292source $testdir/tester.tcl
20c5c4113dSnw141292
21c5c4113dSnw141292# Basic sanity checking.  Try a simple subselect.
22c5c4113dSnw141292#
23c5c4113dSnw141292do_test subselect-1.1 {
24c5c4113dSnw141292  execsql {
25c5c4113dSnw141292    CREATE TABLE t1(a int, b int);
26c5c4113dSnw141292    INSERT INTO t1 VALUES(1,2);
27c5c4113dSnw141292    INSERT INTO t1 VALUES(3,4);
28c5c4113dSnw141292    INSERT INTO t1 VALUES(5,6);
29c5c4113dSnw141292  }
30c5c4113dSnw141292  execsql {SELECT * FROM t1 WHERE a = (SELECT count(*) FROM t1)}
31c5c4113dSnw141292} {3 4}
32c5c4113dSnw141292
33c5c4113dSnw141292# Try a select with more than one result column.
34c5c4113dSnw141292#
35c5c4113dSnw141292do_test subselect-1.2 {
36c5c4113dSnw141292  set v [catch {execsql {SELECT * FROM t1 WHERE a = (SELECT * FROM t1)}} msg]
37c5c4113dSnw141292  lappend v $msg
38c5c4113dSnw141292} {1 {only a single result allowed for a SELECT that is part of an expression}}
39c5c4113dSnw141292
40c5c4113dSnw141292# A subselect without an aggregate.
41c5c4113dSnw141292#
42c5c4113dSnw141292do_test subselect-1.3a {
43c5c4113dSnw141292  execsql {SELECT b from t1 where a = (SELECT a FROM t1 WHERE b=2)}
44c5c4113dSnw141292} {2}
45c5c4113dSnw141292do_test subselect-1.3b {
46c5c4113dSnw141292  execsql {SELECT b from t1 where a = (SELECT a FROM t1 WHERE b=4)}
47c5c4113dSnw141292} {4}
48c5c4113dSnw141292do_test subselect-1.3c {
49c5c4113dSnw141292  execsql {SELECT b from t1 where a = (SELECT a FROM t1 WHERE b=6)}
50c5c4113dSnw141292} {6}
51c5c4113dSnw141292do_test subselect-1.3c {
52c5c4113dSnw141292  execsql {SELECT b from t1 where a = (SELECT a FROM t1 WHERE b=8)}
53c5c4113dSnw141292} {}
54c5c4113dSnw141292
55c5c4113dSnw141292# What if the subselect doesn't return any value.  We should get
56c5c4113dSnw141292# NULL as the result.  Check it out.
57c5c4113dSnw141292#
58c5c4113dSnw141292do_test subselect-1.4 {
59c5c4113dSnw141292  execsql {SELECT b from t1 where a = coalesce((SELECT a FROM t1 WHERE b=5),1)}
60c5c4113dSnw141292} {2}
61c5c4113dSnw141292
62c5c4113dSnw141292# Try multiple subselects within a single expression.
63c5c4113dSnw141292#
64c5c4113dSnw141292do_test subselect-1.5 {
65c5c4113dSnw141292  execsql {
66c5c4113dSnw141292    CREATE TABLE t2(x int, y int);
67c5c4113dSnw141292    INSERT INTO t2 VALUES(1,2);
68c5c4113dSnw141292    INSERT INTO t2 VALUES(2,4);
69c5c4113dSnw141292    INSERT INTO t2 VALUES(3,8);
70c5c4113dSnw141292    INSERT INTO t2 VALUES(4,16);
71c5c4113dSnw141292  }
72c5c4113dSnw141292  execsql {
73c5c4113dSnw141292    SELECT y from t2
74c5c4113dSnw141292    WHERE x = (SELECT sum(b) FROM t1 where a notnull) - (SELECT sum(a) FROM t1)
75c5c4113dSnw141292  }
76c5c4113dSnw141292} {8}
77c5c4113dSnw141292
78c5c4113dSnw141292# Try something useful.  Delete every entry from t2 where the
79c5c4113dSnw141292# x value is less than half of the maximum.
80c5c4113dSnw141292#
81c5c4113dSnw141292do_test subselect-1.6 {
82c5c4113dSnw141292  execsql {DELETE FROM t2 WHERE x < 0.5*(SELECT max(x) FROM t2)}
83c5c4113dSnw141292  execsql {SELECT x FROM t2 ORDER BY x}
84c5c4113dSnw141292} {2 3 4}
85c5c4113dSnw141292
86c5c4113dSnw141292# Make sure sorting works for SELECTs there used as a scalar expression.
87c5c4113dSnw141292#
88c5c4113dSnw141292do_test subselect-2.1 {
89c5c4113dSnw141292  execsql {
90c5c4113dSnw141292    SELECT (SELECT a FROM t1 ORDER BY a), (SELECT a FROM t1 ORDER BY a DESC)
91c5c4113dSnw141292  }
92c5c4113dSnw141292} {1 5}
93c5c4113dSnw141292do_test subselect-2.2 {
94c5c4113dSnw141292  execsql {
95c5c4113dSnw141292    SELECT 1 IN (SELECT a FROM t1 ORDER BY a);
96c5c4113dSnw141292  }
97c5c4113dSnw141292} {1}
98c5c4113dSnw141292do_test subselect-2.3 {
99c5c4113dSnw141292  execsql {
100c5c4113dSnw141292    SELECT 2 IN (SELECT a FROM t1 ORDER BY a DESC);
101c5c4113dSnw141292  }
102c5c4113dSnw141292} {0}
103c5c4113dSnw141292
104c5c4113dSnw141292# Verify that the ORDER BY clause is honored in a subquery.
105c5c4113dSnw141292#
106c5c4113dSnw141292do_test subselect-3.1 {
107c5c4113dSnw141292  execsql {
108c5c4113dSnw141292    CREATE TABLE t3(x int);
109c5c4113dSnw141292    INSERT INTO t3 SELECT a FROM t1 UNION ALL SELECT b FROM t1;
110c5c4113dSnw141292    SELECT * FROM t3 ORDER BY x;
111c5c4113dSnw141292  }
112c5c4113dSnw141292} {1 2 3 4 5 6}
113c5c4113dSnw141292do_test subselect-3.2 {
114c5c4113dSnw141292  execsql {
115c5c4113dSnw141292    SELECT sum(x) FROM (SELECT x FROM t3 ORDER BY x LIMIT 2);
116c5c4113dSnw141292  }
117c5c4113dSnw141292} {3}
118c5c4113dSnw141292do_test subselect-3.3 {
119c5c4113dSnw141292  execsql {
120c5c4113dSnw141292    SELECT sum(x) FROM (SELECT x FROM t3 ORDER BY x DESC LIMIT 2);
121c5c4113dSnw141292  }
122c5c4113dSnw141292} {11}
123c5c4113dSnw141292do_test subselect-3.4 {
124c5c4113dSnw141292  execsql {
125c5c4113dSnw141292    SELECT (SELECT x FROM t3 ORDER BY x);
126c5c4113dSnw141292  }
127c5c4113dSnw141292} {1}
128c5c4113dSnw141292do_test subselect-3.5 {
129c5c4113dSnw141292  execsql {
130c5c4113dSnw141292    SELECT (SELECT x FROM t3 ORDER BY x DESC);
131c5c4113dSnw141292  }
132c5c4113dSnw141292} {6}
133c5c4113dSnw141292do_test subselect-3.6 {
134c5c4113dSnw141292  execsql {
135c5c4113dSnw141292    SELECT (SELECT x FROM t3 ORDER BY x LIMIT 1);
136c5c4113dSnw141292  }
137c5c4113dSnw141292} {1}
138c5c4113dSnw141292do_test subselect-3.7 {
139c5c4113dSnw141292  execsql {
140c5c4113dSnw141292    SELECT (SELECT x FROM t3 ORDER BY x DESC LIMIT 1);
141c5c4113dSnw141292  }
142c5c4113dSnw141292} {6}
143c5c4113dSnw141292do_test subselect-3.8 {
144c5c4113dSnw141292  execsql {
145c5c4113dSnw141292    SELECT (SELECT x FROM t3 ORDER BY x LIMIT 1 OFFSET 2);
146c5c4113dSnw141292  }
147c5c4113dSnw141292} {3}
148c5c4113dSnw141292do_test subselect-3.9 {
149c5c4113dSnw141292  execsql {
150c5c4113dSnw141292    SELECT (SELECT x FROM t3 ORDER BY x DESC LIMIT 1 OFFSET 2);
151c5c4113dSnw141292  }
152c5c4113dSnw141292} {4}
153c5c4113dSnw141292
154c5c4113dSnw141292
155c5c4113dSnw141292
156c5c4113dSnw141292finish_test
157