3 # The author disclaims copyright to this source code. In place of
4 # a legal notice, here is a blessing:
6 # May you do good and not evil.
7 # May you find forgiveness for yourself and forgive others.
8 # May you share freely, never taking more than you give.
10 #***********************************************************************
11 # This file tests the optimisations made in November 2007 of expressions
12 # of the following form:
14 # <value> IN (SELECT <column> FROM <table>)
16 # $Id: in3.test,v 1.5 2008/08/04 03:51:24 danielk1977 Exp $
18 set testdir [file dirname $argv0]
19 source $testdir/tester.tcl
26 # Return the number of OpenEphemeral instructions used in the
27 # implementation of the sql statement passed as a an argument.
29 proc nEphemeral {sql} {
31 foreach op [execsql "EXPLAIN $sql"] {
32 if {$op eq "OpenEphemeral"} {incr nEph}
37 # This proc works the same way as execsql, except that the number
38 # of OpenEphemeral instructions used in the implementation of the
39 # statement is inserted into the start of the returned list.
41 proc exec_neph {sql} {
42 return [concat [nEphemeral $sql] [execsql $sql]]
47 CREATE TABLE t1(a PRIMARY KEY, b);
48 INSERT INTO t1 VALUES(1, 2);
49 INSERT INTO t1 VALUES(3, 4);
50 INSERT INTO t1 VALUES(5, 6);
54 # All of these queries should avoid using a temp-table:
57 exec_neph { SELECT rowid FROM t1 WHERE rowid IN (SELECT rowid FROM t1); }
60 exec_neph { SELECT a FROM t1 WHERE a IN (SELECT a FROM t1); }
63 exec_neph { SELECT rowid FROM t1 WHERE rowid+0 IN (SELECT rowid FROM t1); }
66 exec_neph { SELECT a FROM t1 WHERE a+0 IN (SELECT a FROM t1); }
69 # Because none of the sub-select queries in the following statements
70 # match the pattern ("SELECT <column> FROM <table>"), the following do
71 # require a temp table.
74 exec_neph { SELECT rowid FROM t1 WHERE rowid IN (SELECT rowid+0 FROM t1); }
77 exec_neph { SELECT a FROM t1 WHERE a IN (SELECT a+0 FROM t1); }
80 exec_neph { SELECT a FROM t1 WHERE a IN (SELECT a FROM t1 WHERE 1); }
83 exec_neph { SELECT a FROM t1 WHERE a IN (SELECT a FROM t1 GROUP BY a); }
86 # This should not use a temp-table. Even though the sub-select does
87 # not exactly match the pattern "SELECT <column> FROM <table>", in
88 # this case the ORDER BY is a no-op and can be ignored.
90 exec_neph { SELECT a FROM t1 WHERE a IN (SELECT a FROM t1 ORDER BY a); }
93 # These do use the temp-table. Adding the LIMIT clause means the
94 # ORDER BY cannot be ignored.
96 exec_neph {SELECT a FROM t1 WHERE a IN (SELECT a FROM t1 ORDER BY a LIMIT 1)}
100 SELECT a FROM t1 WHERE a IN (SELECT a FROM t1 ORDER BY a LIMIT 1 OFFSET 1)
104 # Has to use a temp-table because of the compound sub-select.
109 SELECT a FROM t1 WHERE a IN (
110 SELECT a FROM t1 UNION ALL SELECT a FROM t1
116 # The first of these queries has to use the temp-table, because the
117 # collation sequence used for the index on "t1.a" does not match the
118 # collation sequence used by the "IN" comparison. The second does not
119 # require a temp-table, because the collation sequences match.
122 exec_neph { SELECT a FROM t1 WHERE a COLLATE nocase IN (SELECT a FROM t1) }
125 exec_neph { SELECT a FROM t1 WHERE a COLLATE binary IN (SELECT a FROM t1) }
128 # Neither of these queries require a temp-table. The collation sequence
129 # makes no difference when using a rowid.
132 exec_neph {SELECT a FROM t1 WHERE a COLLATE nocase IN (SELECT rowid FROM t1)}
135 exec_neph {SELECT a FROM t1 WHERE a COLLATE binary IN (SELECT rowid FROM t1)}
138 # The following tests - in3.2.* - test a bug that was difficult to track
139 # down during development. They are not particularly well focused.
143 DROP TABLE IF EXISTS t1;
144 CREATE TABLE t1(w int, x int, y int);
145 CREATE TABLE t2(p int, q int, r int, s int);
147 for {set i 1} {$i<=100} {incr i} {
149 set x [expr {int(log($i)/log(2))}]
150 set y [expr {$i*$i + 2*$i + 1}]
151 execsql "INSERT INTO t1 VALUES($w,$x,$y)"
153 set maxy [execsql {select max(y) from t1}]
154 db eval { INSERT INTO t2 SELECT 101-w, x, $maxy+1-y, y FROM t1 }
160 WHERE rowid IN (SELECT rowid FROM t1 WHERE rowid IN (1, 2));
165 select rowid from t1 where rowid IN (-1,2,4)
170 SELECT rowid FROM t1 WHERE rowid IN
171 (select rowid from t1 where rowid IN (-1,2,4))
175 #-------------------------------------------------------------------------
176 # This next block of tests - in3-3.* - verify that column affinity is
177 # correctly handled in cases where an index might be used to optimise
178 # an IN (SELECT) expression.
188 CREATE TABLE t1(a BLOB, b NUMBER ,c TEXT);
189 CREATE UNIQUE INDEX t1_i1 ON t1(a); /* no affinity */
190 CREATE UNIQUE INDEX t1_i2 ON t1(b); /* numeric affinity */
191 CREATE UNIQUE INDEX t1_i3 ON t1(c); /* text affinity */
193 CREATE TABLE t2(x BLOB, y NUMBER, z TEXT);
194 CREATE UNIQUE INDEX t2_i1 ON t2(x); /* no affinity */
195 CREATE UNIQUE INDEX t2_i2 ON t2(y); /* numeric affinity */
196 CREATE UNIQUE INDEX t2_i3 ON t2(z); /* text affinity */
198 INSERT INTO t1 VALUES(1, 1, 1);
199 INSERT INTO t2 VALUES('1', '1', '1');
204 # No affinity is applied before comparing "x" and "a". Therefore
205 # the index can be used (the comparison is false, text!=number).
206 exec_neph { SELECT x IN (SELECT a FROM t1) FROM t2 }
209 # Logically, numeric affinity is applied to both sides before
210 # the comparison. Therefore it is possible to use index t1_i2.
211 exec_neph { SELECT x IN (SELECT b FROM t1) FROM t2 }
214 # No affinity is applied before the comparison takes place. Making
215 # it possible to use index t1_i3.
216 exec_neph { SELECT x IN (SELECT c FROM t1) FROM t2 }
220 # Numeric affinity should be applied to each side before the comparison
221 # takes place. Therefore we cannot use index t1_i1, which has no affinity.
222 exec_neph { SELECT y IN (SELECT a FROM t1) FROM t2 }
225 # Numeric affinity is applied to both sides before
226 # the comparison. Therefore it is possible to use index t1_i2.
227 exec_neph { SELECT y IN (SELECT b FROM t1) FROM t2 }
230 # Numeric affinity is applied before the comparison takes place.
231 # Making it impossible to use index t1_i3.
232 exec_neph { SELECT y IN (SELECT c FROM t1) FROM t2 }
235 #---------------------------------------------------------------------
237 # Test using a multi-column index.
241 CREATE TABLE t3(a, b, c);
242 CREATE UNIQUE INDEX t3_i ON t3(b, a);
246 INSERT INTO t3 VALUES(1, 'numeric', 2);
247 INSERT INTO t3 VALUES(2, 'text', 2);
248 INSERT INTO t3 VALUES(3, 'real', 2);
249 INSERT INTO t3 VALUES(4, 'none', 2);
253 exec_neph { SELECT 'text' IN (SELECT b FROM t3) }
256 exec_neph { SELECT 'TEXT' COLLATE nocase IN (SELECT b FROM t3) }
259 # A temp table must be used because t3_i.b is not guaranteed to be unique.
260 exec_neph { SELECT b FROM t3 WHERE b IN (SELECT b FROM t3) }
261 } {1 none numeric real text}
263 execsql { CREATE UNIQUE INDEX t3_i2 ON t3(b) }
264 exec_neph { SELECT b FROM t3 WHERE b IN (SELECT b FROM t3) }
265 } {0 none numeric real text}
267 execsql { DROP INDEX t3_i2 }
270 # The following two test cases verify that ticket #2991 has been fixed.
274 CREATE TABLE Folders(
275 folderid INTEGER PRIMARY KEY,
284 DELETE FROM Folders WHERE folderid IN
285 (SELECT folderid FROM Folder WHERE path LIKE 'C:\MP3\Albums\' || '%');
287 } {1 {no such table: Folder}}