blob: f95c167f6411c0fb5f003ca4d9bc93995ec95c18 [file] [log] [blame]
danielk197785574e32008-10-06 05:32:18 +00001# 2008 October 4
2#
3# The author disclaims copyright to this source code. In place of
4# a legal notice, here is a blessing:
5#
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.
9#
10#***********************************************************************
11#
drh296a4832009-03-22 20:36:18 +000012# $Id: indexedby.test,v 1.5 2009/03/22 20:36:19 drh Exp $
danielk197785574e32008-10-06 05:32:18 +000013
14set testdir [file dirname $argv0]
15source $testdir/tester.tcl
dane934e632013-08-20 17:14:57 +000016set ::testprefix indexedby
danielk197785574e32008-10-06 05:32:18 +000017
18# Create a schema with some indexes.
19#
20do_test indexedby-1.1 {
21 execsql {
22 CREATE TABLE t1(a, b);
23 CREATE INDEX i1 ON t1(a);
24 CREATE INDEX i2 ON t1(b);
25
26 CREATE TABLE t2(c, d);
27 CREATE INDEX i3 ON t2(c);
28 CREATE INDEX i4 ON t2(d);
29
danielk1977de89c4c2008-10-06 11:29:49 +000030 CREATE TABLE t3(e PRIMARY KEY, f);
31
danielk197785574e32008-10-06 05:32:18 +000032 CREATE VIEW v1 AS SELECT * FROM t1;
33 }
34} {}
35
36# Explain Query Plan
37#
38proc EQP {sql} {
39 uplevel "execsql {EXPLAIN QUERY PLAN $sql}"
40}
41
42# These tests are to check that "EXPLAIN QUERY PLAN" is working as expected.
43#
dan47eb16d2010-11-11 10:36:25 +000044do_execsql_test indexedby-1.2 {
45 EXPLAIN QUERY PLAN select * from t1 WHERE a = 10;
drh5822d6f2013-06-10 23:30:09 +000046} {0 0 0 {SEARCH TABLE t1 USING INDEX i1 (a=?)}}
dan47eb16d2010-11-11 10:36:25 +000047do_execsql_test indexedby-1.3 {
48 EXPLAIN QUERY PLAN select * from t1 ;
drh5822d6f2013-06-10 23:30:09 +000049} {0 0 0 {SCAN TABLE t1}}
dan47eb16d2010-11-11 10:36:25 +000050do_execsql_test indexedby-1.4 {
51 EXPLAIN QUERY PLAN select * from t1, t2 WHERE c = 10;
52} {
drh5822d6f2013-06-10 23:30:09 +000053 0 0 1 {SEARCH TABLE t2 USING INDEX i3 (c=?)}
54 0 1 0 {SCAN TABLE t1}
dan47eb16d2010-11-11 10:36:25 +000055}
danielk197785574e32008-10-06 05:32:18 +000056
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.
61#
62do_test indexedby-2.1 {
63 execsql { SELECT * FROM t1 NOT INDEXED WHERE a = 'one' AND b = 'two'}
64} {}
65do_test indexedby-2.2 {
66 execsql { SELECT * FROM t1 INDEXED BY i1 WHERE a = 'one' AND b = 'two'}
67} {}
68do_test indexedby-2.3 {
69 execsql { SELECT * FROM t1 INDEXED BY i2 WHERE a = 'one' AND b = 'two'}
70} {}
71
72do_test indexedby-2.4 {
73 catchsql { SELECT * FROM t1 INDEXED BY i3 WHERE a = 'one' AND b = 'two'}
74} {1 {no such index: i3}}
75do_test indexedby-2.5 {
76 catchsql { SELECT * FROM t1 INDEXED BY i5 WHERE a = 'one' AND b = 'two'}
77} {1 {no such index: i5}}
78do_test indexedby-2.6 {
79 catchsql { SELECT * FROM t1 INDEXED BY WHERE a = 'one' AND b = 'two'}
80} {1 {near "WHERE": syntax error}}
81do_test indexedby-2.7 {
82 catchsql { SELECT * FROM v1 INDEXED BY i1 WHERE a = 'one' }
83} {1 {no such index: i1}}
84
85# Tests for single table cases.
86#
dan47eb16d2010-11-11 10:36:25 +000087do_execsql_test indexedby-3.1 {
88 EXPLAIN QUERY PLAN SELECT * FROM t1 NOT INDEXED WHERE a = 'one' AND b = 'two'
drh5822d6f2013-06-10 23:30:09 +000089} {0 0 0 {SCAN TABLE t1}}
dan47eb16d2010-11-11 10:36:25 +000090do_execsql_test indexedby-3.2 {
91 EXPLAIN QUERY PLAN
92 SELECT * FROM t1 INDEXED BY i1 WHERE a = 'one' AND b = 'two'
drh5822d6f2013-06-10 23:30:09 +000093} {0 0 0 {SEARCH TABLE t1 USING INDEX i1 (a=?)}}
dan47eb16d2010-11-11 10:36:25 +000094do_execsql_test indexedby-3.3 {
95 EXPLAIN QUERY PLAN
96 SELECT * FROM t1 INDEXED BY i2 WHERE a = 'one' AND b = 'two'
drh5822d6f2013-06-10 23:30:09 +000097} {0 0 0 {SEARCH TABLE t1 USING INDEX i2 (b=?)}}
danielk197785574e32008-10-06 05:32:18 +000098do_test indexedby-3.4 {
99 catchsql { SELECT * FROM t1 INDEXED BY i2 WHERE a = 'one' }
drh4fe425a2013-06-12 17:08:06 +0000100} {1 {no query solution}}
danielk197785574e32008-10-06 05:32:18 +0000101do_test indexedby-3.5 {
102 catchsql { SELECT * FROM t1 INDEXED BY i2 ORDER BY a }
drh4fe425a2013-06-12 17:08:06 +0000103} {1 {no query solution}}
danielk197785574e32008-10-06 05:32:18 +0000104do_test indexedby-3.6 {
105 catchsql { SELECT * FROM t1 INDEXED BY i1 WHERE a = 'one' }
106} {0 {}}
107do_test indexedby-3.7 {
108 catchsql { SELECT * FROM t1 INDEXED BY i1 ORDER BY a }
109} {0 {}}
110
dan47eb16d2010-11-11 10:36:25 +0000111do_execsql_test indexedby-3.8 {
112 EXPLAIN QUERY PLAN
113 SELECT * FROM t3 INDEXED BY sqlite_autoindex_t3_1 ORDER BY e
drh5822d6f2013-06-10 23:30:09 +0000114} {0 0 0 {SCAN TABLE t3 USING INDEX sqlite_autoindex_t3_1}}
dan47eb16d2010-11-11 10:36:25 +0000115do_execsql_test indexedby-3.9 {
116 EXPLAIN QUERY PLAN
117 SELECT * FROM t3 INDEXED BY sqlite_autoindex_t3_1 WHERE e = 10
drh5822d6f2013-06-10 23:30:09 +0000118} {0 0 0 {SEARCH TABLE t3 USING INDEX sqlite_autoindex_t3_1 (e=?)}}
danielk1977de89c4c2008-10-06 11:29:49 +0000119do_test indexedby-3.10 {
120 catchsql { SELECT * FROM t3 INDEXED BY sqlite_autoindex_t3_1 WHERE f = 10 }
drh4fe425a2013-06-12 17:08:06 +0000121} {1 {no query solution}}
danielk1977de89c4c2008-10-06 11:29:49 +0000122do_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}}
125
danielk197785574e32008-10-06 05:32:18 +0000126# Tests for multiple table cases.
127#
dan47eb16d2010-11-11 10:36:25 +0000128do_execsql_test indexedby-4.1 {
129 EXPLAIN QUERY PLAN SELECT * FROM t1, t2 WHERE a = c
130} {
drh5822d6f2013-06-10 23:30:09 +0000131 0 0 0 {SCAN TABLE t1}
132 0 1 1 {SEARCH TABLE t2 USING INDEX i3 (c=?)}
dan47eb16d2010-11-11 10:36:25 +0000133}
134do_execsql_test indexedby-4.2 {
135 EXPLAIN QUERY PLAN SELECT * FROM t1 INDEXED BY i1, t2 WHERE a = c
136} {
drh5822d6f2013-06-10 23:30:09 +0000137 0 0 1 {SCAN TABLE t2}
138 0 1 0 {SEARCH TABLE t1 USING INDEX i1 (a=?)}
dan47eb16d2010-11-11 10:36:25 +0000139}
drh5e377d92010-08-04 21:17:16 +0000140do_test indexedby-4.3 {
141 catchsql {
142 SELECT * FROM t1 INDEXED BY i1, t2 INDEXED BY i3 WHERE a=c
143 }
drh4fe425a2013-06-12 17:08:06 +0000144} {1 {no query solution}}
drh5e377d92010-08-04 21:17:16 +0000145do_test indexedby-4.4 {
146 catchsql {
147 SELECT * FROM t2 INDEXED BY i3, t1 INDEXED BY i1 WHERE a=c
148 }
drh4fe425a2013-06-12 17:08:06 +0000149} {1 {no query solution}}
danielk197785574e32008-10-06 05:32:18 +0000150
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.
154#
dan47eb16d2010-11-11 10:36:25 +0000155do_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
drh5822d6f2013-06-10 23:30:09 +0000158} {0 0 0 {SEARCH TABLE t1 USING INDEX i1 (a>?)}}
dan47eb16d2010-11-11 10:36:25 +0000159do_execsql_test indexedby-5.2 {
160 EXPLAIN QUERY PLAN SELECT * FROM v2 WHERE b = 10
drh5822d6f2013-06-10 23:30:09 +0000161} {0 0 0 {SEARCH TABLE t1 USING INDEX i1 (a>?)}}
danielk197785574e32008-10-06 05:32:18 +0000162do_test indexedby-5.3 {
163 execsql { DROP INDEX i1 }
164 catchsql { SELECT * FROM v2 }
165} {1 {no such index: i1}}
166do_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 }
drh4fe425a2013-06-12 17:08:06 +0000170} {1 {no query solution}}
danielk197785574e32008-10-06 05:32:18 +0000171do_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 }
176} {0 {}}
177
178# Test that "NOT INDEXED" may use the rowid index, but not others.
179#
dan47eb16d2010-11-11 10:36:25 +0000180do_execsql_test indexedby-6.1 {
181 EXPLAIN QUERY PLAN SELECT * FROM t1 WHERE b = 10 ORDER BY rowid
drh5822d6f2013-06-10 23:30:09 +0000182} {0 0 0 {SEARCH TABLE t1 USING INDEX i2 (b=?)}}
dan47eb16d2010-11-11 10:36:25 +0000183do_execsql_test indexedby-6.2 {
184 EXPLAIN QUERY PLAN SELECT * FROM t1 NOT INDEXED WHERE b = 10 ORDER BY rowid
drh4fe425a2013-06-12 17:08:06 +0000185} {0 0 0 {SCAN TABLE t1}}
danielk197785574e32008-10-06 05:32:18 +0000186
danielk1977b1c685b2008-10-06 16:18:39 +0000187# Test that "INDEXED BY" can be used in a DELETE statement.
188#
dan47eb16d2010-11-11 10:36:25 +0000189do_execsql_test indexedby-7.1 {
190 EXPLAIN QUERY PLAN DELETE FROM t1 WHERE a = 5
drh5822d6f2013-06-10 23:30:09 +0000191} {0 0 0 {SEARCH TABLE t1 USING COVERING INDEX i1 (a=?)}}
dan47eb16d2010-11-11 10:36:25 +0000192do_execsql_test indexedby-7.2 {
193 EXPLAIN QUERY PLAN DELETE FROM t1 NOT INDEXED WHERE a = 5
drh5822d6f2013-06-10 23:30:09 +0000194} {0 0 0 {SCAN TABLE t1}}
dan47eb16d2010-11-11 10:36:25 +0000195do_execsql_test indexedby-7.3 {
196 EXPLAIN QUERY PLAN DELETE FROM t1 INDEXED BY i1 WHERE a = 5
drh5822d6f2013-06-10 23:30:09 +0000197} {0 0 0 {SEARCH TABLE t1 USING COVERING INDEX i1 (a=?)}}
dan47eb16d2010-11-11 10:36:25 +0000198do_execsql_test indexedby-7.4 {
199 EXPLAIN QUERY PLAN DELETE FROM t1 INDEXED BY i1 WHERE a = 5 AND b = 10
drh5822d6f2013-06-10 23:30:09 +0000200} {0 0 0 {SEARCH TABLE t1 USING INDEX i1 (a=?)}}
dan47eb16d2010-11-11 10:36:25 +0000201do_execsql_test indexedby-7.5 {
202 EXPLAIN QUERY PLAN DELETE FROM t1 INDEXED BY i2 WHERE a = 5 AND b = 10
drh5822d6f2013-06-10 23:30:09 +0000203} {0 0 0 {SEARCH TABLE t1 USING INDEX i2 (b=?)}}
danielk1977b1c685b2008-10-06 16:18:39 +0000204do_test indexedby-7.6 {
205 catchsql { DELETE FROM t1 INDEXED BY i2 WHERE a = 5}
drh4fe425a2013-06-12 17:08:06 +0000206} {1 {no query solution}}
danielk1977b1c685b2008-10-06 16:18:39 +0000207
208# Test that "INDEXED BY" can be used in an UPDATE statement.
209#
dan47eb16d2010-11-11 10:36:25 +0000210do_execsql_test indexedby-8.1 {
211 EXPLAIN QUERY PLAN UPDATE t1 SET rowid=rowid+1 WHERE a = 5
drh5822d6f2013-06-10 23:30:09 +0000212} {0 0 0 {SEARCH TABLE t1 USING COVERING INDEX i1 (a=?)}}
dan47eb16d2010-11-11 10:36:25 +0000213do_execsql_test indexedby-8.2 {
214 EXPLAIN QUERY PLAN UPDATE t1 NOT INDEXED SET rowid=rowid+1 WHERE a = 5
drh5822d6f2013-06-10 23:30:09 +0000215} {0 0 0 {SCAN TABLE t1}}
dan47eb16d2010-11-11 10:36:25 +0000216do_execsql_test indexedby-8.3 {
217 EXPLAIN QUERY PLAN UPDATE t1 INDEXED BY i1 SET rowid=rowid+1 WHERE a = 5
drh5822d6f2013-06-10 23:30:09 +0000218} {0 0 0 {SEARCH TABLE t1 USING COVERING INDEX i1 (a=?)}}
dan47eb16d2010-11-11 10:36:25 +0000219do_execsql_test indexedby-8.4 {
220 EXPLAIN QUERY PLAN
221 UPDATE t1 INDEXED BY i1 SET rowid=rowid+1 WHERE a = 5 AND b = 10
drh5822d6f2013-06-10 23:30:09 +0000222} {0 0 0 {SEARCH TABLE t1 USING INDEX i1 (a=?)}}
dan47eb16d2010-11-11 10:36:25 +0000223do_execsql_test indexedby-8.5 {
224 EXPLAIN QUERY PLAN
225 UPDATE t1 INDEXED BY i2 SET rowid=rowid+1 WHERE a = 5 AND b = 10
drh5822d6f2013-06-10 23:30:09 +0000226} {0 0 0 {SEARCH TABLE t1 USING INDEX i2 (b=?)}}
danielk1977b1c685b2008-10-06 16:18:39 +0000227do_test indexedby-8.6 {
228 catchsql { UPDATE t1 INDEXED BY i2 SET rowid=rowid+1 WHERE a = 5}
drh4fe425a2013-06-12 17:08:06 +0000229} {1 {no query solution}}
danielk1977b1c685b2008-10-06 16:18:39 +0000230
danielk1977992347f2008-12-30 09:45:45 +0000231# Test that bug #3560 is fixed.
232#
233do_test indexedby-9.1 {
234 execsql {
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);
239 }
240} {}
241do_test indexedby-9.2 {
242 catchsql {
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)
246 }
drh4fe425a2013-06-12 17:08:06 +0000247} {1 {no query solution}}
danielk1977992347f2008-12-30 09:45:45 +0000248do_test indexedby-9.3 {
249 catchsql { select * from maintable, joinme INDEXED by joinme_id_text_idx }
drh4fe425a2013-06-12 17:08:06 +0000250} {1 {no query solution}}
danielk1977992347f2008-12-30 09:45:45 +0000251
drh296a4832009-03-22 20:36:18 +0000252# Make sure we can still create tables, indices, and columns whose name
253# is "indexed".
254#
255do_test indexedby-10.1 {
256 execsql {
257 CREATE TABLE indexed(x,y);
258 INSERT INTO indexed VALUES(1,2);
259 SELECT * FROM indexed;
260 }
261} {1 2}
262do_test indexedby-10.2 {
263 execsql {
264 CREATE INDEX i10 ON indexed(x);
265 SELECT * FROM indexed indexed by i10 where x>0;
266 }
267} {1 2}
268do_test indexedby-10.3 {
269 execsql {
270 DROP TABLE indexed;
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
275 }
276} {1}
danielk197785574e32008-10-06 05:32:18 +0000277
dane934e632013-08-20 17:14:57 +0000278#-------------------------------------------------------------------------
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.
281#
282do_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);
289}
290do_execsql_test 11.2 {
291 SELECT a,b,rowid FROM x1 INDEXED BY x1i WHERE a=1 AND b=1 AND rowid=3;
292} {1 1 3}
293do_execsql_test 11.3 {
294 SELECT a,b,rowid FROM x1 INDEXED BY x1i WHERE a=1 AND b=1 AND rowid='3';
295} {1 1 3}
296do_execsql_test 11.4 {
297 SELECT a,b,rowid FROM x1 INDEXED BY x1i WHERE a=1 AND b=1 AND rowid='3.0';
298} {1 1 3}
299do_eqp_test 11.5 {
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=?)}}
302
303do_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);
310}
311do_execsql_test 11.7 {
312 SELECT a,b,c FROM x2 INDEXED BY x2i WHERE a=1 AND b=1 AND c=3;
313} {1 1 3}
314do_execsql_test 11.8 {
315 SELECT a,b,c FROM x2 INDEXED BY x2i WHERE a=1 AND b=1 AND c='3';
316} {1 1 3}
317do_execsql_test 11.9 {
318 SELECT a,b,c FROM x2 INDEXED BY x2i WHERE a=1 AND b=1 AND c='3.0';
319} {1 1 3}
320do_eqp_test 11.10 {
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=?)}}
323
drh296a4832009-03-22 20:36:18 +0000324finish_test