xref: /sqlite-3.40.0/test/in5.test (revision c324d446)
1dbaee5e3Sdrh# 2012 September 18
2dbaee5e3Sdrh#
3dbaee5e3Sdrh# The author disclaims copyright to this source code.  In place of
4dbaee5e3Sdrh# a legal notice, here is a blessing:
5dbaee5e3Sdrh#
6dbaee5e3Sdrh#    May you do good and not evil.
7dbaee5e3Sdrh#    May you find forgiveness for yourself and forgive others.
8dbaee5e3Sdrh#    May you share freely, never taking more than you give.
9dbaee5e3Sdrh#
10dbaee5e3Sdrh#***********************************************************************
11dbaee5e3Sdrh#
12dbaee5e3Sdrh
13dbaee5e3Sdrhset testdir [file dirname $argv0]
14dbaee5e3Sdrhsource $testdir/tester.tcl
15dd715f7cSdanset testprefix in5
16dbaee5e3Sdrh
17dbaee5e3Sdrhdo_test in5-1.1 {
18dbaee5e3Sdrh  execsql {
19dbaee5e3Sdrh    CREATE TABLE t1x(x INTEGER PRIMARY KEY);
20dbaee5e3Sdrh    INSERT INTO t1x VALUES(1),(3),(5),(7),(9);
21dbaee5e3Sdrh    CREATE TABLE t1y(y INTEGER UNIQUE);
22dbaee5e3Sdrh    INSERT INTO t1y VALUES(2),(4),(6),(8);
23dbaee5e3Sdrh    CREATE TABLE t1z(z TEXT UNIQUE);
24dbaee5e3Sdrh    INSERT INTO t1z VALUES('a'),('c'),('e'),('g');
25dbaee5e3Sdrh    CREATE TABLE t2(a INTEGER, b INTEGER, c TEXT, d TEXT);
26dbaee5e3Sdrh    INSERT INTO t2 VALUES(1,2,'a','12a'),(1,2,'b','12b'),
27dbaee5e3Sdrh                         (2,3,'g','23g'),(3,5,'c','35c'),
28dbaee5e3Sdrh                         (4,6,'h','46h'),(5,6,'e','56e');
29dbaee5e3Sdrh    CREATE TABLE t3x AS SELECT x FROM t1x;
30dbaee5e3Sdrh    CREATE TABLE t3y AS SELECT y FROM t1y;
31dbaee5e3Sdrh    CREATE TABLE t3z AS SELECT z FROM t1z;
32dbaee5e3Sdrh    SELECT d FROM t2 WHERE a IN t1x AND b IN t1y AND c IN t1z ORDER BY c;
33dbaee5e3Sdrh  }
34dbaee5e3Sdrh} {12a 56e}
35dbaee5e3Sdrhdo_test in5-1.2 {
36dbaee5e3Sdrh  execsql {
37dbaee5e3Sdrh    SELECT d FROM t2 WHERE a IN t1y AND b IN t1x AND c IN t1z ORDER BY d;
38dbaee5e3Sdrh  }
39dbaee5e3Sdrh} {23g}
40dbaee5e3Sdrhdo_test in5-1.3 {
41dbaee5e3Sdrh  execsql {
42dbaee5e3Sdrh    SELECT d FROM t2 WHERE a IN t3x AND b IN t3y AND c IN t3z ORDER BY d;
43dbaee5e3Sdrh  }
44dbaee5e3Sdrh} {12a 56e}
45dbaee5e3Sdrh
46dbaee5e3Sdrh
47dbaee5e3Sdrhdo_test in5-2.1 {
48dbaee5e3Sdrh  execsql {
49dbaee5e3Sdrh    CREATE INDEX t2abc ON t2(a,b,c);
50dbaee5e3Sdrh    SELECT d FROM t2 WHERE a IN t1x AND b IN t1y AND c IN t1z ORDER BY d;
51dbaee5e3Sdrh  }
52dbaee5e3Sdrh} {12a 56e}
53dbaee5e3Sdrhdo_test in5-2.2 {
54dbaee5e3Sdrh  execsql {
55dbaee5e3Sdrh    SELECT d FROM t2 WHERE a IN t1y AND b IN t1x AND c IN t1z ORDER BY d;
56dbaee5e3Sdrh  }
57dbaee5e3Sdrh} {23g}
58dbaee5e3Sdrhdo_test in5-2.3 {
59dbaee5e3Sdrh  regexp {OpenEphemeral} [db eval {
60dbaee5e3Sdrh    EXPLAIN SELECT d FROM t2 WHERE a IN t1x AND b IN t1y AND c IN t1z
61dbaee5e3Sdrh  }]
62dbaee5e3Sdrh} {0}
63dbaee5e3Sdrhdo_test in5-2.4 {
64dbaee5e3Sdrh  execsql {
65dbaee5e3Sdrh    SELECT d FROM t2 WHERE a IN t3x AND b IN t3y AND c IN t3z ORDER BY d;
66dbaee5e3Sdrh  }
67dbaee5e3Sdrh} {12a 56e}
68dbaee5e3Sdrhdo_test in5-2.5.1 {
69dbaee5e3Sdrh  regexp {OpenEphemeral} [db eval {
70dbaee5e3Sdrh    EXPLAIN SELECT d FROM t2 WHERE a IN t3x AND b IN t1y AND c IN t1z
71dbaee5e3Sdrh  }]
72dbaee5e3Sdrh} {1}
73dbaee5e3Sdrhdo_test in5-2.5.2 {
74dbaee5e3Sdrh  regexp {OpenEphemeral} [db eval {
75dbaee5e3Sdrh    EXPLAIN SELECT d FROM t2 WHERE a IN t1x AND b IN t3y AND c IN t1z
76dbaee5e3Sdrh  }]
77dbaee5e3Sdrh} {1}
78dbaee5e3Sdrhdo_test in5-2.5.3 {
79dbaee5e3Sdrh  regexp {OpenEphemeral} [db eval {
80dbaee5e3Sdrh    EXPLAIN SELECT d FROM t2 WHERE a IN t1x AND b IN t1y AND c IN t3z
81dbaee5e3Sdrh  }]
82dbaee5e3Sdrh} {1}
83dbaee5e3Sdrh
84dbaee5e3Sdrhdo_test in5-3.1 {
85dbaee5e3Sdrh  execsql {
86dbaee5e3Sdrh    DROP INDEX t2abc;
87dbaee5e3Sdrh    CREATE INDEX t2ab ON t2(a,b);
88dbaee5e3Sdrh    SELECT d FROM t2 WHERE a IN t1x AND b IN t1y AND c IN t1z ORDER BY d;
89dbaee5e3Sdrh  }
90dbaee5e3Sdrh} {12a 56e}
91dbaee5e3Sdrhdo_test in5-3.2 {
92dbaee5e3Sdrh  execsql {
93dbaee5e3Sdrh    SELECT d FROM t2 WHERE a IN t1y AND b IN t1x AND c IN t1z ORDER BY d;
94dbaee5e3Sdrh  }
95dbaee5e3Sdrh} {23g}
96dbaee5e3Sdrhdo_test in5-3.3 {
97dbaee5e3Sdrh  regexp {OpenEphemeral} [db eval {
98dbaee5e3Sdrh    EXPLAIN SELECT d FROM t2 WHERE a IN t1x AND b IN t1y AND c IN t1z
99dbaee5e3Sdrh  }]
100dbaee5e3Sdrh} {0}
101dbaee5e3Sdrh
102dbaee5e3Sdrhdo_test in5-4.1 {
103dbaee5e3Sdrh  execsql {
104dbaee5e3Sdrh    DROP INDEX t2ab;
105dbaee5e3Sdrh    CREATE INDEX t2abcd ON t2(a,b,c,d);
106dbaee5e3Sdrh    SELECT d FROM t2 WHERE a IN t1x AND b IN t1y AND c IN t1z ORDER BY d;
107dbaee5e3Sdrh  }
108dbaee5e3Sdrh} {12a 56e}
109dbaee5e3Sdrhdo_test in5-4.2 {
110dbaee5e3Sdrh  execsql {
111dbaee5e3Sdrh    SELECT d FROM t2 WHERE a IN t1y AND b IN t1x AND c IN t1z ORDER BY d;
112dbaee5e3Sdrh  }
113dbaee5e3Sdrh} {23g}
114dbaee5e3Sdrhdo_test in5-4.3 {
115dbaee5e3Sdrh  regexp {OpenEphemeral} [db eval {
116dbaee5e3Sdrh    EXPLAIN SELECT d FROM t2 WHERE a IN t1x AND b IN t1y AND c IN t1z
117dbaee5e3Sdrh  }]
118dbaee5e3Sdrh} {0}
119dbaee5e3Sdrh
120dbaee5e3Sdrh
121dbaee5e3Sdrhdo_test in5-5.1 {
122dbaee5e3Sdrh  execsql {
123dbaee5e3Sdrh    DROP INDEX t2abcd;
124dbaee5e3Sdrh    CREATE INDEX t2cbad ON t2(c,b,a,d);
125dbaee5e3Sdrh    SELECT d FROM t2 WHERE a IN t1x AND b IN t1y AND c IN t1z ORDER BY d;
126dbaee5e3Sdrh  }
127dbaee5e3Sdrh} {12a 56e}
128dbaee5e3Sdrhdo_test in5-5.2 {
129dbaee5e3Sdrh  execsql {
130dbaee5e3Sdrh    SELECT d FROM t2 WHERE a IN t1y AND b IN t1x AND c IN t1z ORDER BY d;
131dbaee5e3Sdrh  }
132dbaee5e3Sdrh} {23g}
133dbaee5e3Sdrhdo_test in5-5.3 {
134dbaee5e3Sdrh  regexp {OpenEphemeral} [db eval {
135dbaee5e3Sdrh    EXPLAIN SELECT d FROM t2 WHERE a IN t1x AND b IN t1y AND c IN t1z
136dbaee5e3Sdrh  }]
137dbaee5e3Sdrh} {0}
138dbaee5e3Sdrh
139dd715f7cSdan#-------------------------------------------------------------------------
140dd715f7cSdan# At one point SQLite was removing the DISTINCT keyword from expressions
141dd715f7cSdan# similar to:
142dd715f7cSdan#
143dd715f7cSdan#   <expr1> IN (SELECT DISTINCT <expr2> FROM...)
144dd715f7cSdan#
145dd715f7cSdan# However, there are a few obscure cases where this is incorrect. For
146dd715f7cSdan# example, if the SELECT features a LIMIT clause, or if the collation
147dd715f7cSdan# sequence or affinity used by the DISTINCT does not match the one used
148dd715f7cSdan# by the IN(...) expression.
149dd715f7cSdan#
150dd715f7cSdando_execsql_test 6.1.1 {
151dd715f7cSdan  CREATE TABLE t1(a COLLATE nocase);
152dd715f7cSdan  INSERT INTO t1 VALUES('one');
153dd715f7cSdan  INSERT INTO t1 VALUES('ONE');
154dd715f7cSdan}
155dd715f7cSdando_execsql_test 6.1.2 {
156dd715f7cSdan  SELECT count(*) FROM t1 WHERE a COLLATE BINARY IN (SELECT DISTINCT a FROM t1)
157dd715f7cSdan} {1}
158dd715f7cSdan
159dd715f7cSdando_execsql_test 6.2.1 {
160dd715f7cSdan  CREATE TABLE t3(a, b);
161dd715f7cSdan  INSERT INTO t3 VALUES(1, 1);
162dd715f7cSdan  INSERT INTO t3 VALUES(1, 2);
163dd715f7cSdan  INSERT INTO t3 VALUES(1, 3);
164dd715f7cSdan  INSERT INTO t3 VALUES(2, 4);
165dd715f7cSdan  INSERT INTO t3 VALUES(2, 5);
166dd715f7cSdan  INSERT INTO t3 VALUES(2, 6);
167dd715f7cSdan  INSERT INTO t3 VALUES(3, 7);
168dd715f7cSdan  INSERT INTO t3 VALUES(3, 8);
169dd715f7cSdan  INSERT INTO t3 VALUES(3, 9);
170dd715f7cSdan}
171dd715f7cSdando_execsql_test 6.2.2 {
172dd715f7cSdan  SELECT count(*) FROM t3 WHERE b IN (SELECT DISTINCT a FROM t3 LIMIT 5);
173dd715f7cSdan} {3}
174dd715f7cSdando_execsql_test 6.2.3 {
175dd715f7cSdan  SELECT count(*) FROM t3 WHERE b IN (SELECT          a FROM t3 LIMIT 5);
176dd715f7cSdan} {2}
177dd715f7cSdan
178dd715f7cSdando_execsql_test 6.3.1 {
179dd715f7cSdan  CREATE TABLE x1(a);
180dd715f7cSdan  CREATE TABLE x2(b);
181dd715f7cSdan  INSERT INTO x1 VALUES(1), (1), (2);
182dd715f7cSdan  INSERT INTO x2 VALUES(1), (2);
183dd715f7cSdan  SELECT count(*) FROM x2 WHERE b IN (SELECT DISTINCT a FROM x1 LIMIT 2);
184dd715f7cSdan} {2}
185dd715f7cSdan
186ab8aa11bSdan#-------------------------------------------------------------------------
187ab8aa11bSdan# Test to confirm that bug [5e3c886796e5] is fixed.
188ab8aa11bSdan#
189ab8aa11bSdando_execsql_test 7.1 {
190ab8aa11bSdan  CREATE TABLE y1(a, b);
191ab8aa11bSdan  CREATE TABLE y2(c);
192ab8aa11bSdan
193ab8aa11bSdan  INSERT INTO y1 VALUES(1,     'one');
194ab8aa11bSdan  INSERT INTO y1 VALUES('two', 'two');
195ab8aa11bSdan  INSERT INTO y1 VALUES(3,     'three');
196ab8aa11bSdan
197ab8aa11bSdan  INSERT INTO y2 VALUES('one');
198ab8aa11bSdan  INSERT INTO y2 VALUES('two');
199ab8aa11bSdan  INSERT INTO y2 VALUES('three');
200ab8aa11bSdan} {}
201ab8aa11bSdan
202ab8aa11bSdando_execsql_test 7.2.1 {
203ab8aa11bSdan  SELECT a FROM y1 WHERE b NOT IN (SELECT a FROM y2);
204ab8aa11bSdan} {1 3}
205ab8aa11bSdando_execsql_test 7.2.2 {
206ab8aa11bSdan  SELECT a FROM y1 WHERE b IN (SELECT a FROM y2);
207ab8aa11bSdan} {two}
208ab8aa11bSdan
209ab8aa11bSdando_execsql_test 7.3.1 {
210ab8aa11bSdan  CREATE INDEX y2c ON y2(c);
211ab8aa11bSdan  SELECT a FROM y1 WHERE b NOT IN (SELECT a FROM y2);
212ab8aa11bSdan} {1 3}
213ab8aa11bSdando_execsql_test 7.3.2 {
214ab8aa11bSdan  SELECT a FROM y1 WHERE b IN (SELECT a FROM y2);
215ab8aa11bSdan} {two}
216ab8aa11bSdan
217edc3537cSdan#-------------------------------------------------------------------------
218edc3537cSdan# Tests to confirm that indexes on the rowid column do not confuse
219edc3537cSdan# the query planner. See ticket [0eab1ac7591f511d].
220edc3537cSdan#
221edc3537cSdando_execsql_test 8.0 {
222edc3537cSdan  CREATE TABLE n1(a INTEGER PRIMARY KEY, b VARCHAR(500));
223edc3537cSdan  CREATE UNIQUE INDEX n1a ON n1(a);
224edc3537cSdan}
225ab8aa11bSdan
226edc3537cSdando_execsql_test 8.1 {
227edc3537cSdan  SELECT count(*) FROM n1 WHERE a IN (1, 2, 3)
228edc3537cSdan} 0
229edc3537cSdando_execsql_test 8.2 {
230edc3537cSdan  SELECT count(*) FROM n1 WHERE a IN (SELECT +a FROM n1)
231edc3537cSdan} 0
232edc3537cSdando_execsql_test 8.3 {
233edc3537cSdan  INSERT INTO n1 VALUES(1, NULL), (2, NULL), (3, NULL);
234edc3537cSdan  SELECT count(*) FROM n1 WHERE a IN (1, 2, 3)
235edc3537cSdan} 3
236edc3537cSdando_execsql_test 8.4 {
237edc3537cSdan  SELECT count(*) FROM n1 WHERE a IN (SELECT +a FROM n1)
238edc3537cSdan} 3
239ab8aa11bSdan
240a1188d6dSdan#-------------------------------------------------------------------------
241a1188d6dSdan# Test that ticket 61fe97454c is fixed.
242a1188d6dSdan#
243a1188d6dSdando_execsql_test 9.0 {
244a1188d6dSdan  CREATE TABLE t9(a INTEGER PRIMARY KEY);
245a1188d6dSdan  INSERT INTO t9 VALUES (44), (45);
246a1188d6dSdan}
247a1188d6dSdando_execsql_test 9.1 {
248a1188d6dSdan  SELECT * FROM t9 WHERE a IN (44, 45, 44, 45)
249a1188d6dSdan} {44 45}
250a1188d6dSdan
251*c324d446Sdan#-------------------------------------------------------------------------
252*c324d446Sdan# Test that ticket c7a117190 is fixed.
253*c324d446Sdan#
254*c324d446Sdanreset_db
255*c324d446Sdando_execsql_test 9.0 {
256*c324d446Sdan  CREATE TABLE t0(c0);
257*c324d446Sdan  CREATE VIEW v0(c0) AS SELECT LOWER(CAST('1e500' AS TEXT)) FROM t0;
258*c324d446Sdan  INSERT INTO t0(c0) VALUES (NULL);
259*c324d446Sdan}
260*c324d446Sdan
261*c324d446Sdando_execsql_test 9.1 {
262*c324d446Sdan  SELECT lower('1e500') FROM t0 WHERE rowid NOT IN (0, 0, lower('1e500'));
263*c324d446Sdan} {1e500}
264*c324d446Sdan
265*c324d446Sdando_execsql_test 9.2 {
266*c324d446Sdan  SELECT lower('1e500') FROM t0 WHERE rowid != lower('1e500');
267*c324d446Sdan} {1e500}
268a1188d6dSdan
269dbaee5e3Sdrhfinish_test
270