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 #***********************************************************************
12 # $Id: indexedby.test,v 1.5 2009/03/22 20:36:19 drh Exp $
14 set testdir [file dirname $argv0]
15 source $testdir/tester.tcl
16 set ::testprefix indexedby
18 # Create a schema with some indexes.
20 do_test indexedby-1.1 {
22 CREATE TABLE t1(a, b);
23 CREATE INDEX i1 ON t1(a);
24 CREATE INDEX i2 ON t1(b);
26 CREATE TABLE t2(c, d);
27 CREATE INDEX i3 ON t2(c);
28 CREATE INDEX i4 ON t2(d);
30 CREATE TABLE t3(e PRIMARY KEY, f);
32 CREATE VIEW v1 AS SELECT * FROM t1;
39 uplevel "execsql {EXPLAIN QUERY PLAN $sql}"
42 # These tests are to check that "EXPLAIN QUERY PLAN" is working as expected.
44 do_execsql_test indexedby-1.2 {
45 EXPLAIN QUERY PLAN select * from t1 WHERE a = 10;
46 } {0 0 0 {SEARCH TABLE t1 USING INDEX i1 (a=?)}}
47 do_execsql_test indexedby-1.3 {
48 EXPLAIN QUERY PLAN select * from t1 ;
49 } {0 0 0 {SCAN TABLE t1}}
50 do_execsql_test indexedby-1.4 {
51 EXPLAIN QUERY PLAN select * from t1, t2 WHERE c = 10;
53 0 0 1 {SEARCH TABLE t2 USING INDEX i3 (c=?)}
57 # Parser tests. Test that an INDEXED BY or NOT INDEX clause can be
58 # attached to a table in the FROM clause, but not to a sub-select or
59 # SQL view. Also test that specifying an index that does not exist or
60 # is attached to a different table is detected as an error.
62 do_test indexedby-2.1 {
63 execsql { SELECT * FROM t1 NOT INDEXED WHERE a = 'one' AND b = 'two'}
65 do_test indexedby-2.2 {
66 execsql { SELECT * FROM t1 INDEXED BY i1 WHERE a = 'one' AND b = 'two'}
68 do_test indexedby-2.3 {
69 execsql { SELECT * FROM t1 INDEXED BY i2 WHERE a = 'one' AND b = 'two'}
72 do_test indexedby-2.4 {
73 catchsql { SELECT * FROM t1 INDEXED BY i3 WHERE a = 'one' AND b = 'two'}
74 } {1 {no such index: i3}}
75 do_test indexedby-2.5 {
76 catchsql { SELECT * FROM t1 INDEXED BY i5 WHERE a = 'one' AND b = 'two'}
77 } {1 {no such index: i5}}
78 do_test indexedby-2.6 {
79 catchsql { SELECT * FROM t1 INDEXED BY WHERE a = 'one' AND b = 'two'}
80 } {1 {near "WHERE": syntax error}}
81 do_test indexedby-2.7 {
82 catchsql { SELECT * FROM v1 INDEXED BY i1 WHERE a = 'one' }
83 } {1 {no such index: i1}}
85 # Tests for single table cases.
87 do_execsql_test indexedby-3.1 {
88 EXPLAIN QUERY PLAN SELECT * FROM t1 NOT INDEXED WHERE a = 'one' AND b = 'two'
89 } {0 0 0 {SCAN TABLE t1}}
90 do_execsql_test indexedby-3.2 {
92 SELECT * FROM t1 INDEXED BY i1 WHERE a = 'one' AND b = 'two'
93 } {0 0 0 {SEARCH TABLE t1 USING INDEX i1 (a=?)}}
94 do_execsql_test indexedby-3.3 {
96 SELECT * FROM t1 INDEXED BY i2 WHERE a = 'one' AND b = 'two'
97 } {0 0 0 {SEARCH TABLE t1 USING INDEX i2 (b=?)}}
98 do_test indexedby-3.4 {
99 catchsql { SELECT * FROM t1 INDEXED BY i2 WHERE a = 'one' }
100 } {1 {no query solution}}
101 do_test indexedby-3.5 {
102 catchsql { SELECT * FROM t1 INDEXED BY i2 ORDER BY a }
103 } {1 {no query solution}}
104 do_test indexedby-3.6 {
105 catchsql { SELECT * FROM t1 INDEXED BY i1 WHERE a = 'one' }
107 do_test indexedby-3.7 {
108 catchsql { SELECT * FROM t1 INDEXED BY i1 ORDER BY a }
111 do_execsql_test indexedby-3.8 {
113 SELECT * FROM t3 INDEXED BY sqlite_autoindex_t3_1 ORDER BY e
114 } {0 0 0 {SCAN TABLE t3 USING INDEX sqlite_autoindex_t3_1}}
115 do_execsql_test indexedby-3.9 {
117 SELECT * FROM t3 INDEXED BY sqlite_autoindex_t3_1 WHERE e = 10
118 } {0 0 0 {SEARCH TABLE t3 USING INDEX sqlite_autoindex_t3_1 (e=?)}}
119 do_test indexedby-3.10 {
120 catchsql { SELECT * FROM t3 INDEXED BY sqlite_autoindex_t3_1 WHERE f = 10 }
121 } {1 {no query solution}}
122 do_test indexedby-3.11 {
123 catchsql { SELECT * FROM t3 INDEXED BY sqlite_autoindex_t3_2 WHERE f = 10 }
124 } {1 {no such index: sqlite_autoindex_t3_2}}
126 # Tests for multiple table cases.
128 do_execsql_test indexedby-4.1 {
129 EXPLAIN QUERY PLAN SELECT * FROM t1, t2 WHERE a = c
131 0 0 0 {SCAN TABLE t1}
132 0 1 1 {SEARCH TABLE t2 USING INDEX i3 (c=?)}
134 do_execsql_test indexedby-4.2 {
135 EXPLAIN QUERY PLAN SELECT * FROM t1 INDEXED BY i1, t2 WHERE a = c
137 0 0 1 {SCAN TABLE t2}
138 0 1 0 {SEARCH TABLE t1 USING INDEX i1 (a=?)}
140 do_test indexedby-4.3 {
142 SELECT * FROM t1 INDEXED BY i1, t2 INDEXED BY i3 WHERE a=c
144 } {1 {no query solution}}
145 do_test indexedby-4.4 {
147 SELECT * FROM t2 INDEXED BY i3, t1 INDEXED BY i1 WHERE a=c
149 } {1 {no query solution}}
151 # Test embedding an INDEXED BY in a CREATE VIEW statement. This block
152 # also tests that nothing bad happens if an index refered to by
153 # a CREATE VIEW statement is dropped and recreated.
155 do_execsql_test indexedby-5.1 {
156 CREATE VIEW v2 AS SELECT * FROM t1 INDEXED BY i1 WHERE a > 5;
157 EXPLAIN QUERY PLAN SELECT * FROM v2
158 } {0 0 0 {SEARCH TABLE t1 USING INDEX i1 (a>?)}}
159 do_execsql_test indexedby-5.2 {
160 EXPLAIN QUERY PLAN SELECT * FROM v2 WHERE b = 10
161 } {0 0 0 {SEARCH TABLE t1 USING INDEX i1 (a>?)}}
162 do_test indexedby-5.3 {
163 execsql { DROP INDEX i1 }
164 catchsql { SELECT * FROM v2 }
165 } {1 {no such index: i1}}
166 do_test indexedby-5.4 {
167 # Recreate index i1 in such a way as it cannot be used by the view query.
168 execsql { CREATE INDEX i1 ON t1(b) }
169 catchsql { SELECT * FROM v2 }
170 } {1 {no query solution}}
171 do_test indexedby-5.5 {
172 # Drop and recreate index i1 again. This time, create it so that it can
173 # be used by the query.
174 execsql { DROP INDEX i1 ; CREATE INDEX i1 ON t1(a) }
175 catchsql { SELECT * FROM v2 }
178 # Test that "NOT INDEXED" may use the rowid index, but not others.
180 do_execsql_test indexedby-6.1 {
181 EXPLAIN QUERY PLAN SELECT * FROM t1 WHERE b = 10 ORDER BY rowid
182 } {0 0 0 {SEARCH TABLE t1 USING INDEX i2 (b=?)}}
183 do_execsql_test indexedby-6.2 {
184 EXPLAIN QUERY PLAN SELECT * FROM t1 NOT INDEXED WHERE b = 10 ORDER BY rowid
185 } {0 0 0 {SCAN TABLE t1}}
187 # Test that "INDEXED BY" can be used in a DELETE statement.
189 do_execsql_test indexedby-7.1 {
190 EXPLAIN QUERY PLAN DELETE FROM t1 WHERE a = 5
191 } {0 0 0 {SEARCH TABLE t1 USING COVERING INDEX i1 (a=?)}}
192 do_execsql_test indexedby-7.2 {
193 EXPLAIN QUERY PLAN DELETE FROM t1 NOT INDEXED WHERE a = 5
194 } {0 0 0 {SCAN TABLE t1}}
195 do_execsql_test indexedby-7.3 {
196 EXPLAIN QUERY PLAN DELETE FROM t1 INDEXED BY i1 WHERE a = 5
197 } {0 0 0 {SEARCH TABLE t1 USING COVERING INDEX i1 (a=?)}}
198 do_execsql_test indexedby-7.4 {
199 EXPLAIN QUERY PLAN DELETE FROM t1 INDEXED BY i1 WHERE a = 5 AND b = 10
200 } {0 0 0 {SEARCH TABLE t1 USING INDEX i1 (a=?)}}
201 do_execsql_test indexedby-7.5 {
202 EXPLAIN QUERY PLAN DELETE FROM t1 INDEXED BY i2 WHERE a = 5 AND b = 10
203 } {0 0 0 {SEARCH TABLE t1 USING INDEX i2 (b=?)}}
204 do_test indexedby-7.6 {
205 catchsql { DELETE FROM t1 INDEXED BY i2 WHERE a = 5}
206 } {1 {no query solution}}
208 # Test that "INDEXED BY" can be used in an UPDATE statement.
210 do_execsql_test indexedby-8.1 {
211 EXPLAIN QUERY PLAN UPDATE t1 SET rowid=rowid+1 WHERE a = 5
212 } {0 0 0 {SEARCH TABLE t1 USING COVERING INDEX i1 (a=?)}}
213 do_execsql_test indexedby-8.2 {
214 EXPLAIN QUERY PLAN UPDATE t1 NOT INDEXED SET rowid=rowid+1 WHERE a = 5
215 } {0 0 0 {SCAN TABLE t1}}
216 do_execsql_test indexedby-8.3 {
217 EXPLAIN QUERY PLAN UPDATE t1 INDEXED BY i1 SET rowid=rowid+1 WHERE a = 5
218 } {0 0 0 {SEARCH TABLE t1 USING COVERING INDEX i1 (a=?)}}
219 do_execsql_test indexedby-8.4 {
221 UPDATE t1 INDEXED BY i1 SET rowid=rowid+1 WHERE a = 5 AND b = 10
222 } {0 0 0 {SEARCH TABLE t1 USING INDEX i1 (a=?)}}
223 do_execsql_test indexedby-8.5 {
225 UPDATE t1 INDEXED BY i2 SET rowid=rowid+1 WHERE a = 5 AND b = 10
226 } {0 0 0 {SEARCH TABLE t1 USING INDEX i2 (b=?)}}
227 do_test indexedby-8.6 {
228 catchsql { UPDATE t1 INDEXED BY i2 SET rowid=rowid+1 WHERE a = 5}
229 } {1 {no query solution}}
231 # Test that bug #3560 is fixed.
233 do_test indexedby-9.1 {
235 CREATE TABLE maintable( id integer);
236 CREATE TABLE joinme(id_int integer, id_text text);
237 CREATE INDEX joinme_id_text_idx on joinme(id_text);
238 CREATE INDEX joinme_id_int_idx on joinme(id_int);
241 do_test indexedby-9.2 {
243 select * from maintable as m inner join
244 joinme as j indexed by joinme_id_text_idx
245 on ( m.id = j.id_int)
247 } {1 {no query solution}}
248 do_test indexedby-9.3 {
249 catchsql { select * from maintable, joinme INDEXED by joinme_id_text_idx }
250 } {1 {no query solution}}
252 # Make sure we can still create tables, indices, and columns whose name
255 do_test indexedby-10.1 {
257 CREATE TABLE indexed(x,y);
258 INSERT INTO indexed VALUES(1,2);
259 SELECT * FROM indexed;
262 do_test indexedby-10.2 {
264 CREATE INDEX i10 ON indexed(x);
265 SELECT * FROM indexed indexed by i10 where x>0;
268 do_test indexedby-10.3 {
271 CREATE TABLE t10(indexed INTEGER);
272 INSERT INTO t10 VALUES(1);
273 CREATE INDEX indexed ON t10(indexed);
274 SELECT * FROM t10 indexed by indexed WHERE indexed>0
278 #-------------------------------------------------------------------------
279 # Ensure that the rowid at the end of each index entry may be used
280 # for equality constraints in the same way as other indexed fields.
282 do_execsql_test 11.1 {
283 CREATE TABLE x1(a, b TEXT);
284 CREATE INDEX x1i ON x1(a, b);
285 INSERT INTO x1 VALUES(1, 1);
286 INSERT INTO x1 VALUES(1, 1);
287 INSERT INTO x1 VALUES(1, 1);
288 INSERT INTO x1 VALUES(1, 1);
290 do_execsql_test 11.2 {
291 SELECT a,b,rowid FROM x1 INDEXED BY x1i WHERE a=1 AND b=1 AND rowid=3;
293 do_execsql_test 11.3 {
294 SELECT a,b,rowid FROM x1 INDEXED BY x1i WHERE a=1 AND b=1 AND rowid='3';
296 do_execsql_test 11.4 {
297 SELECT a,b,rowid FROM x1 INDEXED BY x1i WHERE a=1 AND b=1 AND rowid='3.0';
300 SELECT a,b,rowid FROM x1 INDEXED BY x1i WHERE a=1 AND b=1 AND rowid='3.0';
301 } {0 0 0 {SEARCH TABLE x1 USING COVERING INDEX x1i (a=? AND b=? AND rowid=?)}}
303 do_execsql_test 11.6 {
304 CREATE TABLE x2(c INTEGER PRIMARY KEY, a, b TEXT);
305 CREATE INDEX x2i ON x2(a, b);
306 INSERT INTO x2 VALUES(1, 1, 1);
307 INSERT INTO x2 VALUES(2, 1, 1);
308 INSERT INTO x2 VALUES(3, 1, 1);
309 INSERT INTO x2 VALUES(4, 1, 1);
311 do_execsql_test 11.7 {
312 SELECT a,b,c FROM x2 INDEXED BY x2i WHERE a=1 AND b=1 AND c=3;
314 do_execsql_test 11.8 {
315 SELECT a,b,c FROM x2 INDEXED BY x2i WHERE a=1 AND b=1 AND c='3';
317 do_execsql_test 11.9 {
318 SELECT a,b,c FROM x2 INDEXED BY x2i WHERE a=1 AND b=1 AND c='3.0';
321 SELECT a,b,c FROM x2 INDEXED BY x2i WHERE a=1 AND b=1 AND c='3.0';
322 } {0 0 0 {SEARCH TABLE x2 USING COVERING INDEX x2i (a=? AND b=? AND rowid=?)}}