summaryrefslogtreecommitdiff
path: root/test/indexedby.test
blob: f95c167f6411c0fb5f003ca4d9bc93995ec95c18 (plain)
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
84
85
86
87
88
89
90
91
92
93
94
95
96
97
98
99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
121
122
123
124
125
126
127
128
129
130
131
132
133
134
135
136
137
138
139
140
141
142
143
144
145
146
147
148
149
150
151
152
153
154
155
156
157
158
159
160
161
162
163
164
165
166
167
168
169
170
171
172
173
174
175
176
177
178
179
180
181
182
183
184
185
186
187
188
189
190
191
192
193
194
195
196
197
198
199
200
201
202
203
204
205
206
207
208
209
210
211
212
213
214
215
216
217
218
219
220
221
222
223
224
225
226
227
228
229
230
231
232
233
234
235
236
237
238
239
240
241
242
243
244
245
246
247
248
249
250
251
252
253
254
255
256
257
258
259
260
261
262
263
264
265
266
267
268
269
270
271
272
273
274
275
276
277
278
279
280
281
282
283
284
285
286
287
288
289
290
291
292
293
294
295
296
297
298
299
300
301
302
303
304
305
306
307
308
309
310
311
312
313
314
315
316
317
318
319
320
321
322
323
324
# 2008 October 4
#
# The author disclaims copyright to this source code.  In place of
# a legal notice, here is a blessing:
#
#    May you do good and not evil.
#    May you find forgiveness for yourself and forgive others.
#    May you share freely, never taking more than you give.
#
#***********************************************************************
#
# $Id: indexedby.test,v 1.5 2009/03/22 20:36:19 drh Exp $

set testdir [file dirname $argv0]
source $testdir/tester.tcl
set ::testprefix indexedby

# Create a schema with some indexes.
#
do_test indexedby-1.1 {
  execsql {
    CREATE TABLE t1(a, b);
    CREATE INDEX i1 ON t1(a);
    CREATE INDEX i2 ON t1(b);

    CREATE TABLE t2(c, d);
    CREATE INDEX i3 ON t2(c);
    CREATE INDEX i4 ON t2(d);

    CREATE TABLE t3(e PRIMARY KEY, f);

    CREATE VIEW v1 AS SELECT * FROM t1;
  }
} {}

# Explain Query Plan
#
proc EQP {sql} {
  uplevel "execsql {EXPLAIN QUERY PLAN $sql}"
}

# These tests are to check that "EXPLAIN QUERY PLAN" is working as expected.
#
do_execsql_test indexedby-1.2 {
  EXPLAIN QUERY PLAN select * from t1 WHERE a = 10; 
} {0 0 0 {SEARCH TABLE t1 USING INDEX i1 (a=?)}}
do_execsql_test indexedby-1.3 {
  EXPLAIN QUERY PLAN select * from t1 ; 
} {0 0 0 {SCAN TABLE t1}}
do_execsql_test indexedby-1.4 {
  EXPLAIN QUERY PLAN select * from t1, t2 WHERE c = 10; 
} {
  0 0 1 {SEARCH TABLE t2 USING INDEX i3 (c=?)} 
  0 1 0 {SCAN TABLE t1}
}

# Parser tests. Test that an INDEXED BY or NOT INDEX clause can be 
# attached to a table in the FROM clause, but not to a sub-select or
# SQL view. Also test that specifying an index that does not exist or
# is attached to a different table is detected as an error.
# 
do_test indexedby-2.1 {
  execsql { SELECT * FROM t1 NOT INDEXED WHERE a = 'one' AND b = 'two'}
} {}
do_test indexedby-2.2 {
  execsql { SELECT * FROM t1 INDEXED BY i1 WHERE a = 'one' AND b = 'two'}
} {}
do_test indexedby-2.3 {
  execsql { SELECT * FROM t1 INDEXED BY i2 WHERE a = 'one' AND b = 'two'}
} {}

do_test indexedby-2.4 {
  catchsql { SELECT * FROM t1 INDEXED BY i3 WHERE a = 'one' AND b = 'two'}
} {1 {no such index: i3}}
do_test indexedby-2.5 {
  catchsql { SELECT * FROM t1 INDEXED BY i5 WHERE a = 'one' AND b = 'two'}
} {1 {no such index: i5}}
do_test indexedby-2.6 {
  catchsql { SELECT * FROM t1 INDEXED BY WHERE a = 'one' AND b = 'two'}
} {1 {near "WHERE": syntax error}}
do_test indexedby-2.7 {
  catchsql { SELECT * FROM v1 INDEXED BY i1 WHERE a = 'one' }
} {1 {no such index: i1}}

# Tests for single table cases.
#
do_execsql_test indexedby-3.1 {
  EXPLAIN QUERY PLAN SELECT * FROM t1 NOT INDEXED WHERE a = 'one' AND b = 'two'
} {0 0 0 {SCAN TABLE t1}}
do_execsql_test indexedby-3.2 {
  EXPLAIN QUERY PLAN 
  SELECT * FROM t1 INDEXED BY i1 WHERE a = 'one' AND b = 'two'
} {0 0 0 {SEARCH TABLE t1 USING INDEX i1 (a=?)}}
do_execsql_test indexedby-3.3 {
  EXPLAIN QUERY PLAN 
  SELECT * FROM t1 INDEXED BY i2 WHERE a = 'one' AND b = 'two'
} {0 0 0 {SEARCH TABLE t1 USING INDEX i2 (b=?)}}
do_test indexedby-3.4 {
  catchsql { SELECT * FROM t1 INDEXED BY i2 WHERE a = 'one' }
} {1 {no query solution}}
do_test indexedby-3.5 {
  catchsql { SELECT * FROM t1 INDEXED BY i2 ORDER BY a }
} {1 {no query solution}}
do_test indexedby-3.6 {
  catchsql { SELECT * FROM t1 INDEXED BY i1 WHERE a = 'one' }
} {0 {}}
do_test indexedby-3.7 {
  catchsql { SELECT * FROM t1 INDEXED BY i1 ORDER BY a }
} {0 {}}

do_execsql_test indexedby-3.8 {
  EXPLAIN QUERY PLAN 
  SELECT * FROM t3 INDEXED BY sqlite_autoindex_t3_1 ORDER BY e 
} {0 0 0 {SCAN TABLE t3 USING INDEX sqlite_autoindex_t3_1}}
do_execsql_test indexedby-3.9 {
  EXPLAIN QUERY PLAN 
  SELECT * FROM t3 INDEXED BY sqlite_autoindex_t3_1 WHERE e = 10 
} {0 0 0 {SEARCH TABLE t3 USING INDEX sqlite_autoindex_t3_1 (e=?)}}
do_test indexedby-3.10 {
  catchsql { SELECT * FROM t3 INDEXED BY sqlite_autoindex_t3_1 WHERE f = 10 }
} {1 {no query solution}}
do_test indexedby-3.11 {
  catchsql { SELECT * FROM t3 INDEXED BY sqlite_autoindex_t3_2 WHERE f = 10 }
} {1 {no such index: sqlite_autoindex_t3_2}}

# Tests for multiple table cases.
#
do_execsql_test indexedby-4.1 {
  EXPLAIN QUERY PLAN SELECT * FROM t1, t2 WHERE a = c 
} {
  0 0 0 {SCAN TABLE t1} 
  0 1 1 {SEARCH TABLE t2 USING INDEX i3 (c=?)}
}
do_execsql_test indexedby-4.2 {
  EXPLAIN QUERY PLAN SELECT * FROM t1 INDEXED BY i1, t2 WHERE a = c 
} {
  0 0 1 {SCAN TABLE t2} 
  0 1 0 {SEARCH TABLE t1 USING INDEX i1 (a=?)}
}
do_test indexedby-4.3 {
  catchsql {
    SELECT * FROM t1 INDEXED BY i1, t2 INDEXED BY i3 WHERE a=c
  }
} {1 {no query solution}}
do_test indexedby-4.4 {
  catchsql {
    SELECT * FROM t2 INDEXED BY i3, t1 INDEXED BY i1 WHERE a=c
  }
} {1 {no query solution}}

# Test embedding an INDEXED BY in a CREATE VIEW statement. This block
# also tests that nothing bad happens if an index refered to by
# a CREATE VIEW statement is dropped and recreated.
#
do_execsql_test indexedby-5.1 {
  CREATE VIEW v2 AS SELECT * FROM t1 INDEXED BY i1 WHERE a > 5;
  EXPLAIN QUERY PLAN SELECT * FROM v2 
} {0 0 0 {SEARCH TABLE t1 USING INDEX i1 (a>?)}}
do_execsql_test indexedby-5.2 {
  EXPLAIN QUERY PLAN SELECT * FROM v2 WHERE b = 10 
} {0 0 0 {SEARCH TABLE t1 USING INDEX i1 (a>?)}}
do_test indexedby-5.3 {
  execsql { DROP INDEX i1 }
  catchsql { SELECT * FROM v2 }
} {1 {no such index: i1}}
do_test indexedby-5.4 {
  # Recreate index i1 in such a way as it cannot be used by the view query.
  execsql { CREATE INDEX i1 ON t1(b) }
  catchsql { SELECT * FROM v2 }
} {1 {no query solution}}
do_test indexedby-5.5 {
  # Drop and recreate index i1 again. This time, create it so that it can
  # be used by the query.
  execsql { DROP INDEX i1 ; CREATE INDEX i1 ON t1(a) }
  catchsql { SELECT * FROM v2 }
} {0 {}}

# Test that "NOT INDEXED" may use the rowid index, but not others.
# 
do_execsql_test indexedby-6.1 {
  EXPLAIN QUERY PLAN SELECT * FROM t1 WHERE b = 10 ORDER BY rowid 
} {0 0 0 {SEARCH TABLE t1 USING INDEX i2 (b=?)}}
do_execsql_test indexedby-6.2 {
  EXPLAIN QUERY PLAN SELECT * FROM t1 NOT INDEXED WHERE b = 10 ORDER BY rowid 
} {0 0 0 {SCAN TABLE t1}}

# Test that "INDEXED BY" can be used in a DELETE statement.
# 
do_execsql_test indexedby-7.1 {
  EXPLAIN QUERY PLAN DELETE FROM t1 WHERE a = 5 
} {0 0 0 {SEARCH TABLE t1 USING COVERING INDEX i1 (a=?)}}
do_execsql_test indexedby-7.2 {
  EXPLAIN QUERY PLAN DELETE FROM t1 NOT INDEXED WHERE a = 5 
} {0 0 0 {SCAN TABLE t1}}
do_execsql_test indexedby-7.3 {
  EXPLAIN QUERY PLAN DELETE FROM t1 INDEXED BY i1 WHERE a = 5 
} {0 0 0 {SEARCH TABLE t1 USING COVERING INDEX i1 (a=?)}}
do_execsql_test indexedby-7.4 {
  EXPLAIN QUERY PLAN DELETE FROM t1 INDEXED BY i1 WHERE a = 5 AND b = 10
} {0 0 0 {SEARCH TABLE t1 USING INDEX i1 (a=?)}}
do_execsql_test indexedby-7.5 {
  EXPLAIN QUERY PLAN DELETE FROM t1 INDEXED BY i2 WHERE a = 5 AND b = 10
} {0 0 0 {SEARCH TABLE t1 USING INDEX i2 (b=?)}}
do_test indexedby-7.6 {
  catchsql { DELETE FROM t1 INDEXED BY i2 WHERE a = 5}
} {1 {no query solution}}

# Test that "INDEXED BY" can be used in an UPDATE statement.
# 
do_execsql_test indexedby-8.1 {
  EXPLAIN QUERY PLAN UPDATE t1 SET rowid=rowid+1 WHERE a = 5 
} {0 0 0 {SEARCH TABLE t1 USING COVERING INDEX i1 (a=?)}}
do_execsql_test indexedby-8.2 {
  EXPLAIN QUERY PLAN UPDATE t1 NOT INDEXED SET rowid=rowid+1 WHERE a = 5 
} {0 0 0 {SCAN TABLE t1}}
do_execsql_test indexedby-8.3 {
  EXPLAIN QUERY PLAN UPDATE t1 INDEXED BY i1 SET rowid=rowid+1 WHERE a = 5 
} {0 0 0 {SEARCH TABLE t1 USING COVERING INDEX i1 (a=?)}}
do_execsql_test indexedby-8.4 {
  EXPLAIN QUERY PLAN 
  UPDATE t1 INDEXED BY i1 SET rowid=rowid+1 WHERE a = 5 AND b = 10
} {0 0 0 {SEARCH TABLE t1 USING INDEX i1 (a=?)}}
do_execsql_test indexedby-8.5 {
  EXPLAIN QUERY PLAN 
  UPDATE t1 INDEXED BY i2 SET rowid=rowid+1 WHERE a = 5 AND b = 10
} {0 0 0 {SEARCH TABLE t1 USING INDEX i2 (b=?)}}
do_test indexedby-8.6 {
  catchsql { UPDATE t1 INDEXED BY i2 SET rowid=rowid+1 WHERE a = 5}
} {1 {no query solution}}

# Test that bug #3560 is fixed.
#
do_test indexedby-9.1 {
  execsql {
    CREATE TABLE maintable( id integer);
    CREATE TABLE joinme(id_int integer, id_text text);
    CREATE INDEX joinme_id_text_idx on joinme(id_text);
    CREATE INDEX joinme_id_int_idx on joinme(id_int);
  }
} {}
do_test indexedby-9.2 {
  catchsql {
    select * from maintable as m inner join
    joinme as j indexed by joinme_id_text_idx
    on ( m.id  = j.id_int)
  }
} {1 {no query solution}}
do_test indexedby-9.3 {
  catchsql { select * from maintable, joinme INDEXED by joinme_id_text_idx }
} {1 {no query solution}}

# Make sure we can still create tables, indices, and columns whose name
# is "indexed".
#
do_test indexedby-10.1 {
  execsql {
    CREATE TABLE indexed(x,y);
    INSERT INTO indexed VALUES(1,2);
    SELECT * FROM indexed;
  }
} {1 2}
do_test indexedby-10.2 {
  execsql {
    CREATE INDEX i10 ON indexed(x);
    SELECT * FROM indexed indexed by i10 where x>0;
  }
} {1 2}
do_test indexedby-10.3 {
  execsql {
    DROP TABLE indexed;
    CREATE TABLE t10(indexed INTEGER);
    INSERT INTO t10 VALUES(1);
    CREATE INDEX indexed ON t10(indexed);
    SELECT * FROM t10 indexed by indexed WHERE indexed>0
  }
} {1}

#-------------------------------------------------------------------------
# Ensure that the rowid at the end of each index entry may be used
# for equality constraints in the same way as other indexed fields.
#
do_execsql_test 11.1 {
  CREATE TABLE x1(a, b TEXT);
  CREATE INDEX x1i ON x1(a, b);
  INSERT INTO x1 VALUES(1, 1);
  INSERT INTO x1 VALUES(1, 1);
  INSERT INTO x1 VALUES(1, 1);
  INSERT INTO x1 VALUES(1, 1);
}
do_execsql_test 11.2 {
  SELECT a,b,rowid FROM x1 INDEXED BY x1i WHERE a=1 AND b=1 AND rowid=3;
} {1 1 3}
do_execsql_test 11.3 {
  SELECT a,b,rowid FROM x1 INDEXED BY x1i WHERE a=1 AND b=1 AND rowid='3';
} {1 1 3}
do_execsql_test 11.4 {
  SELECT a,b,rowid FROM x1 INDEXED BY x1i WHERE a=1 AND b=1 AND rowid='3.0';
} {1 1 3}
do_eqp_test 11.5 {
  SELECT a,b,rowid FROM x1 INDEXED BY x1i WHERE a=1 AND b=1 AND rowid='3.0';
} {0 0 0 {SEARCH TABLE x1 USING COVERING INDEX x1i (a=? AND b=? AND rowid=?)}}

do_execsql_test 11.6 {
  CREATE TABLE x2(c INTEGER PRIMARY KEY, a, b TEXT);
  CREATE INDEX x2i ON x2(a, b);
  INSERT INTO x2 VALUES(1, 1, 1);
  INSERT INTO x2 VALUES(2, 1, 1);
  INSERT INTO x2 VALUES(3, 1, 1);
  INSERT INTO x2 VALUES(4, 1, 1);
}
do_execsql_test 11.7 {
  SELECT a,b,c FROM x2 INDEXED BY x2i WHERE a=1 AND b=1 AND c=3;
} {1 1 3}
do_execsql_test 11.8 {
  SELECT a,b,c FROM x2 INDEXED BY x2i WHERE a=1 AND b=1 AND c='3';
} {1 1 3}
do_execsql_test 11.9 {
  SELECT a,b,c FROM x2 INDEXED BY x2i WHERE a=1 AND b=1 AND c='3.0';
} {1 1 3}
do_eqp_test 11.10 {
  SELECT a,b,c FROM x2 INDEXED BY x2i WHERE a=1 AND b=1 AND c='3.0';
} {0 0 0 {SEARCH TABLE x2 USING COVERING INDEX x2i (a=? AND b=? AND rowid=?)}}

finish_test