xref: /titanic_52/usr/src/lib/libsqlite/test/in.test (revision c5c4113dfcabb1eed3d4bdf7609de5170027a794)
1*c5c4113dSnw141292
2*c5c4113dSnw141292#pragma ident	"%Z%%M%	%I%	%E% SMI"
3*c5c4113dSnw141292
4*c5c4113dSnw141292# 2001 September 15
5*c5c4113dSnw141292#
6*c5c4113dSnw141292# The author disclaims copyright to this source code.  In place of
7*c5c4113dSnw141292# a legal notice, here is a blessing:
8*c5c4113dSnw141292#
9*c5c4113dSnw141292#    May you do good and not evil.
10*c5c4113dSnw141292#    May you find forgiveness for yourself and forgive others.
11*c5c4113dSnw141292#    May you share freely, never taking more than you give.
12*c5c4113dSnw141292#
13*c5c4113dSnw141292#***********************************************************************
14*c5c4113dSnw141292# This file implements regression tests for SQLite library.  The
15*c5c4113dSnw141292# focus of this file is testing the IN and BETWEEN operator.
16*c5c4113dSnw141292#
17*c5c4113dSnw141292# $Id: in.test,v 1.11 2004/01/15 03:30:25 drh Exp $
18*c5c4113dSnw141292
19*c5c4113dSnw141292set testdir [file dirname $argv0]
20*c5c4113dSnw141292source $testdir/tester.tcl
21*c5c4113dSnw141292
22*c5c4113dSnw141292# Generate the test data we will need for the first squences of tests.
23*c5c4113dSnw141292#
24*c5c4113dSnw141292do_test in-1.0 {
25*c5c4113dSnw141292  set fd [open data1.txt w]
26*c5c4113dSnw141292  for {set i 1} {$i<=10} {incr i} {
27*c5c4113dSnw141292    puts $fd "$i\t[expr {int(pow(2,$i))}]"
28*c5c4113dSnw141292  }
29*c5c4113dSnw141292  close $fd
30*c5c4113dSnw141292  execsql {
31*c5c4113dSnw141292    CREATE TABLE t1(a int, b int);
32*c5c4113dSnw141292    COPY t1 FROM 'data1.txt';
33*c5c4113dSnw141292  }
34*c5c4113dSnw141292  file delete -force data1.txt
35*c5c4113dSnw141292  execsql {SELECT count(*) FROM t1}
36*c5c4113dSnw141292} {10}
37*c5c4113dSnw141292
38*c5c4113dSnw141292# Do basic testing of BETWEEN.
39*c5c4113dSnw141292#
40*c5c4113dSnw141292do_test in-1.1 {
41*c5c4113dSnw141292  execsql {SELECT a FROM t1 WHERE b BETWEEN 10 AND 50 ORDER BY a}
42*c5c4113dSnw141292} {4 5}
43*c5c4113dSnw141292do_test in-1.2 {
44*c5c4113dSnw141292  execsql {SELECT a FROM t1 WHERE b NOT BETWEEN 10 AND 50 ORDER BY a}
45*c5c4113dSnw141292} {1 2 3 6 7 8 9 10}
46*c5c4113dSnw141292do_test in-1.3 {
47*c5c4113dSnw141292  execsql {SELECT a FROM t1 WHERE b BETWEEN a AND a*5 ORDER BY a}
48*c5c4113dSnw141292} {1 2 3 4}
49*c5c4113dSnw141292do_test in-1.4 {
50*c5c4113dSnw141292  execsql {SELECT a FROM t1 WHERE b NOT BETWEEN a AND a*5 ORDER BY a}
51*c5c4113dSnw141292} {5 6 7 8 9 10}
52*c5c4113dSnw141292do_test in-1.6 {
53*c5c4113dSnw141292  execsql {SELECT a FROM t1 WHERE b BETWEEN a AND a*5 OR b=512 ORDER BY a}
54*c5c4113dSnw141292} {1 2 3 4 9}
55*c5c4113dSnw141292do_test in-1.7 {
56*c5c4113dSnw141292  execsql {SELECT a+ 100*(a BETWEEN 1 and 3) FROM t1 ORDER BY b}
57*c5c4113dSnw141292} {101 102 103 4 5 6 7 8 9 10}
58*c5c4113dSnw141292
59*c5c4113dSnw141292
60*c5c4113dSnw141292# Testing of the IN operator using static lists on the right-hand side.
61*c5c4113dSnw141292#
62*c5c4113dSnw141292do_test in-2.1 {
63*c5c4113dSnw141292  execsql {SELECT a FROM t1 WHERE b IN (8,12,16,24,32) ORDER BY a}
64*c5c4113dSnw141292} {3 4 5}
65*c5c4113dSnw141292do_test in-2.2 {
66*c5c4113dSnw141292  execsql {SELECT a FROM t1 WHERE b NOT IN (8,12,16,24,32) ORDER BY a}
67*c5c4113dSnw141292} {1 2 6 7 8 9 10}
68*c5c4113dSnw141292do_test in-2.3 {
69*c5c4113dSnw141292  execsql {SELECT a FROM t1 WHERE b IN (8,12,16,24,32) OR b=512 ORDER BY a}
70*c5c4113dSnw141292} {3 4 5 9}
71*c5c4113dSnw141292do_test in-2.4 {
72*c5c4113dSnw141292  execsql {SELECT a FROM t1 WHERE b NOT IN (8,12,16,24,32) OR b=512 ORDER BY a}
73*c5c4113dSnw141292} {1 2 6 7 8 9 10}
74*c5c4113dSnw141292do_test in-2.5 {
75*c5c4113dSnw141292  execsql {SELECT a+100*(b IN (8,16,24)) FROM t1 ORDER BY b}
76*c5c4113dSnw141292} {1 2 103 104 5 6 7 8 9 10}
77*c5c4113dSnw141292
78*c5c4113dSnw141292do_test in-2.6 {
79*c5c4113dSnw141292  set v [catch {execsql {SELECT a FROM t1 WHERE b IN (b+10,20)}} msg]
80*c5c4113dSnw141292  lappend v $msg
81*c5c4113dSnw141292} {1 {right-hand side of IN operator must be constant}}
82*c5c4113dSnw141292do_test in-2.7 {
83*c5c4113dSnw141292  set v [catch {execsql {SELECT a FROM t1 WHERE b IN (max(5,10,b),20)}} msg]
84*c5c4113dSnw141292  lappend v $msg
85*c5c4113dSnw141292} {1 {right-hand side of IN operator must be constant}}
86*c5c4113dSnw141292do_test in-2.8 {
87*c5c4113dSnw141292  execsql {SELECT a FROM t1 WHERE b IN (8*2,64/2) ORDER BY b}
88*c5c4113dSnw141292} {4 5}
89*c5c4113dSnw141292do_test in-2.9 {
90*c5c4113dSnw141292  set v [catch {execsql {SELECT a FROM t1 WHERE b IN (max(5,10),20)}} msg]
91*c5c4113dSnw141292  lappend v $msg
92*c5c4113dSnw141292} {1 {right-hand side of IN operator must be constant}}
93*c5c4113dSnw141292do_test in-2.10 {
94*c5c4113dSnw141292  set v [catch {execsql {SELECT a FROM t1 WHERE min(0,b IN (a,30))}} msg]
95*c5c4113dSnw141292  lappend v $msg
96*c5c4113dSnw141292} {1 {right-hand side of IN operator must be constant}}
97*c5c4113dSnw141292do_test in-2.11 {
98*c5c4113dSnw141292  set v [catch {execsql {SELECT a FROM t1 WHERE c IN (10,20)}} msg]
99*c5c4113dSnw141292  lappend v $msg
100*c5c4113dSnw141292} {1 {no such column: c}}
101*c5c4113dSnw141292
102*c5c4113dSnw141292# Testing the IN operator where the right-hand side is a SELECT
103*c5c4113dSnw141292#
104*c5c4113dSnw141292do_test in-3.1 {
105*c5c4113dSnw141292  execsql {
106*c5c4113dSnw141292    SELECT a FROM t1
107*c5c4113dSnw141292    WHERE b IN (SELECT b FROM t1 WHERE a<5)
108*c5c4113dSnw141292    ORDER BY a
109*c5c4113dSnw141292  }
110*c5c4113dSnw141292} {1 2 3 4}
111*c5c4113dSnw141292do_test in-3.2 {
112*c5c4113dSnw141292  execsql {
113*c5c4113dSnw141292    SELECT a FROM t1
114*c5c4113dSnw141292    WHERE b IN (SELECT b FROM t1 WHERE a<5) OR b==512
115*c5c4113dSnw141292    ORDER BY a
116*c5c4113dSnw141292  }
117*c5c4113dSnw141292} {1 2 3 4 9}
118*c5c4113dSnw141292do_test in-3.3 {
119*c5c4113dSnw141292  execsql {
120*c5c4113dSnw141292    SELECT a + 100*(b IN (SELECT b FROM t1 WHERE a<5)) FROM t1 ORDER BY b
121*c5c4113dSnw141292  }
122*c5c4113dSnw141292} {101 102 103 104 5 6 7 8 9 10}
123*c5c4113dSnw141292
124*c5c4113dSnw141292# Make sure the UPDATE and DELETE commands work with IN-SELECT
125*c5c4113dSnw141292#
126*c5c4113dSnw141292do_test in-4.1 {
127*c5c4113dSnw141292  execsql {
128*c5c4113dSnw141292    UPDATE t1 SET b=b*2
129*c5c4113dSnw141292    WHERE b IN (SELECT b FROM t1 WHERE a>8)
130*c5c4113dSnw141292  }
131*c5c4113dSnw141292  execsql {SELECT b FROM t1 ORDER BY b}
132*c5c4113dSnw141292} {2 4 8 16 32 64 128 256 1024 2048}
133*c5c4113dSnw141292do_test in-4.2 {
134*c5c4113dSnw141292  execsql {
135*c5c4113dSnw141292    DELETE FROM t1 WHERE b IN (SELECT b FROM t1 WHERE a>8)
136*c5c4113dSnw141292  }
137*c5c4113dSnw141292  execsql {SELECT a FROM t1 ORDER BY a}
138*c5c4113dSnw141292} {1 2 3 4 5 6 7 8}
139*c5c4113dSnw141292do_test in-4.3 {
140*c5c4113dSnw141292  execsql {
141*c5c4113dSnw141292    DELETE FROM t1 WHERE b NOT IN (SELECT b FROM t1 WHERE a>4)
142*c5c4113dSnw141292  }
143*c5c4113dSnw141292  execsql {SELECT a FROM t1 ORDER BY a}
144*c5c4113dSnw141292} {5 6 7 8}
145*c5c4113dSnw141292
146*c5c4113dSnw141292# Do an IN with a constant RHS but where the RHS has many, many
147*c5c4113dSnw141292# elements.  We need to test that collisions in the hash table
148*c5c4113dSnw141292# are resolved properly.
149*c5c4113dSnw141292#
150*c5c4113dSnw141292do_test in-5.1 {
151*c5c4113dSnw141292  execsql {
152*c5c4113dSnw141292    INSERT INTO t1 VALUES('hello', 'world');
153*c5c4113dSnw141292    SELECT * FROM t1
154*c5c4113dSnw141292    WHERE a IN (
155*c5c4113dSnw141292       'Do','an','IN','with','a','constant','RHS','but','where','the',
156*c5c4113dSnw141292       'has','many','elements','We','need','to','test','that',
157*c5c4113dSnw141292       'collisions','hash','table','are','resolved','properly',
158*c5c4113dSnw141292       'This','in-set','contains','thirty','one','entries','hello');
159*c5c4113dSnw141292  }
160*c5c4113dSnw141292} {hello world}
161*c5c4113dSnw141292
162*c5c4113dSnw141292# Make sure the IN operator works with INTEGER PRIMARY KEY fields.
163*c5c4113dSnw141292#
164*c5c4113dSnw141292do_test in-6.1 {
165*c5c4113dSnw141292  execsql {
166*c5c4113dSnw141292    CREATE TABLE ta(a INTEGER PRIMARY KEY, b);
167*c5c4113dSnw141292    INSERT INTO ta VALUES(1,1);
168*c5c4113dSnw141292    INSERT INTO ta VALUES(2,2);
169*c5c4113dSnw141292    INSERT INTO ta VALUES(3,3);
170*c5c4113dSnw141292    INSERT INTO ta VALUES(4,4);
171*c5c4113dSnw141292    INSERT INTO ta VALUES(6,6);
172*c5c4113dSnw141292    INSERT INTO ta VALUES(8,8);
173*c5c4113dSnw141292    INSERT INTO ta VALUES(10,
174*c5c4113dSnw141292       'This is a key that is long enough to require a malloc in the VDBE');
175*c5c4113dSnw141292    SELECT * FROM ta WHERE a<10;
176*c5c4113dSnw141292  }
177*c5c4113dSnw141292} {1 1 2 2 3 3 4 4 6 6 8 8}
178*c5c4113dSnw141292do_test in-6.2 {
179*c5c4113dSnw141292  execsql {
180*c5c4113dSnw141292    CREATE TABLE tb(a INTEGER PRIMARY KEY, b);
181*c5c4113dSnw141292    INSERT INTO tb VALUES(1,1);
182*c5c4113dSnw141292    INSERT INTO tb VALUES(2,2);
183*c5c4113dSnw141292    INSERT INTO tb VALUES(3,3);
184*c5c4113dSnw141292    INSERT INTO tb VALUES(5,5);
185*c5c4113dSnw141292    INSERT INTO tb VALUES(7,7);
186*c5c4113dSnw141292    INSERT INTO tb VALUES(9,9);
187*c5c4113dSnw141292    INSERT INTO tb VALUES(11,
188*c5c4113dSnw141292       'This is a key that is long enough to require a malloc in the VDBE');
189*c5c4113dSnw141292    SELECT * FROM tb WHERE a<10;
190*c5c4113dSnw141292  }
191*c5c4113dSnw141292} {1 1 2 2 3 3 5 5 7 7 9 9}
192*c5c4113dSnw141292do_test in-6.3 {
193*c5c4113dSnw141292  execsql {
194*c5c4113dSnw141292    SELECT a FROM ta WHERE b IN (SELECT a FROM tb);
195*c5c4113dSnw141292  }
196*c5c4113dSnw141292} {1 2 3}
197*c5c4113dSnw141292do_test in-6.4 {
198*c5c4113dSnw141292  execsql {
199*c5c4113dSnw141292    SELECT a FROM ta WHERE b NOT IN (SELECT a FROM tb);
200*c5c4113dSnw141292  }
201*c5c4113dSnw141292} {4 6 8 10}
202*c5c4113dSnw141292do_test in-6.5 {
203*c5c4113dSnw141292  execsql {
204*c5c4113dSnw141292    SELECT a FROM ta WHERE b IN (SELECT b FROM tb);
205*c5c4113dSnw141292  }
206*c5c4113dSnw141292} {1 2 3 10}
207*c5c4113dSnw141292do_test in-6.6 {
208*c5c4113dSnw141292  execsql {
209*c5c4113dSnw141292    SELECT a FROM ta WHERE b NOT IN (SELECT b FROM tb);
210*c5c4113dSnw141292  }
211*c5c4113dSnw141292} {4 6 8}
212*c5c4113dSnw141292do_test in-6.7 {
213*c5c4113dSnw141292  execsql {
214*c5c4113dSnw141292    SELECT a FROM ta WHERE a IN (SELECT a FROM tb);
215*c5c4113dSnw141292  }
216*c5c4113dSnw141292} {1 2 3}
217*c5c4113dSnw141292do_test in-6.8 {
218*c5c4113dSnw141292  execsql {
219*c5c4113dSnw141292    SELECT a FROM ta WHERE a NOT IN (SELECT a FROM tb);
220*c5c4113dSnw141292  }
221*c5c4113dSnw141292} {4 6 8 10}
222*c5c4113dSnw141292do_test in-6.9 {
223*c5c4113dSnw141292  execsql {
224*c5c4113dSnw141292    SELECT a FROM ta WHERE a IN (SELECT b FROM tb);
225*c5c4113dSnw141292  }
226*c5c4113dSnw141292} {1 2 3}
227*c5c4113dSnw141292do_test in-6.10 {
228*c5c4113dSnw141292  execsql {
229*c5c4113dSnw141292    SELECT a FROM ta WHERE a NOT IN (SELECT b FROM tb);
230*c5c4113dSnw141292  }
231*c5c4113dSnw141292} {4 6 8 10}
232*c5c4113dSnw141292
233*c5c4113dSnw141292# Tests of IN operator against empty sets.  (Ticket #185)
234*c5c4113dSnw141292#
235*c5c4113dSnw141292do_test in-7.1 {
236*c5c4113dSnw141292  execsql {
237*c5c4113dSnw141292    SELECT a FROM t1 WHERE a IN ();
238*c5c4113dSnw141292  }
239*c5c4113dSnw141292} {}
240*c5c4113dSnw141292do_test in-7.2 {
241*c5c4113dSnw141292  execsql {
242*c5c4113dSnw141292    SELECT a FROM t1 WHERE a IN (5);
243*c5c4113dSnw141292  }
244*c5c4113dSnw141292} {5}
245*c5c4113dSnw141292do_test in-7.3 {
246*c5c4113dSnw141292  execsql {
247*c5c4113dSnw141292    SELECT a FROM t1 WHERE a NOT IN () ORDER BY a;
248*c5c4113dSnw141292  }
249*c5c4113dSnw141292} {5 6 7 8 hello}
250*c5c4113dSnw141292do_test in-7.4 {
251*c5c4113dSnw141292  execsql {
252*c5c4113dSnw141292    SELECT a FROM t1 WHERE a IN (5) AND b IN ();
253*c5c4113dSnw141292  }
254*c5c4113dSnw141292} {}
255*c5c4113dSnw141292do_test in-7.5 {
256*c5c4113dSnw141292  execsql {
257*c5c4113dSnw141292    SELECT a FROM t1 WHERE a IN (5) AND b NOT IN ();
258*c5c4113dSnw141292  }
259*c5c4113dSnw141292} {5}
260*c5c4113dSnw141292do_test in-7.6 {
261*c5c4113dSnw141292  execsql {
262*c5c4113dSnw141292    SELECT a FROM ta WHERE a IN ();
263*c5c4113dSnw141292  }
264*c5c4113dSnw141292} {}
265*c5c4113dSnw141292do_test in-7.7 {
266*c5c4113dSnw141292  execsql {
267*c5c4113dSnw141292    SELECT a FROM ta WHERE a NOT IN ();
268*c5c4113dSnw141292  }
269*c5c4113dSnw141292} {1 2 3 4 6 8 10}
270*c5c4113dSnw141292
271*c5c4113dSnw141292do_test in-8.1 {
272*c5c4113dSnw141292  execsql {
273*c5c4113dSnw141292    SELECT b FROM t1 WHERE a IN ('hello','there')
274*c5c4113dSnw141292  }
275*c5c4113dSnw141292} {world}
276*c5c4113dSnw141292do_test in-8.2 {
277*c5c4113dSnw141292  execsql {
278*c5c4113dSnw141292    SELECT b FROM t1 WHERE a IN ("hello",'there')
279*c5c4113dSnw141292  }
280*c5c4113dSnw141292} {world}
281*c5c4113dSnw141292
282*c5c4113dSnw141292# Test constructs of the form:  expr IN tablename
283*c5c4113dSnw141292#
284*c5c4113dSnw141292do_test in-9.1 {
285*c5c4113dSnw141292  execsql {
286*c5c4113dSnw141292    CREATE TABLE t4 AS SELECT a FROM tb;
287*c5c4113dSnw141292    SELECT * FROM t4;
288*c5c4113dSnw141292  }
289*c5c4113dSnw141292} {1 2 3 5 7 9 11}
290*c5c4113dSnw141292do_test in-9.2 {
291*c5c4113dSnw141292  execsql {
292*c5c4113dSnw141292    SELECT b FROM t1 WHERE a IN t4;
293*c5c4113dSnw141292  }
294*c5c4113dSnw141292} {32 128}
295*c5c4113dSnw141292do_test in-9.3 {
296*c5c4113dSnw141292  execsql {
297*c5c4113dSnw141292    SELECT b FROM t1 WHERE a NOT IN t4;
298*c5c4113dSnw141292  }
299*c5c4113dSnw141292} {64 256 world}
300*c5c4113dSnw141292do_test in-9.4 {
301*c5c4113dSnw141292  catchsql {
302*c5c4113dSnw141292    SELECT b FROM t1 WHERE a NOT IN tb;
303*c5c4113dSnw141292  }
304*c5c4113dSnw141292} {1 {only a single result allowed for a SELECT that is part of an expression}}
305*c5c4113dSnw141292
306*c5c4113dSnw141292finish_test
307