blob: 69fae49feb5aa46c3f63bfa3aaeea3ca6a990724 [file] [log] [blame]
drh1fe05372013-07-31 18:12:26 +00001# 2013-07-31
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#
12# Test cases for partial indices
13#
14
15
16set testdir [file dirname $argv0]
17source $testdir/tester.tcl
18
danc3c16cb2013-08-20 20:25:03 +000019ifcapable !vtab {
20 finish_test
21 return
22}
23
drh1fe05372013-07-31 18:12:26 +000024load_static_extension db wholenumber;
25do_test index6-1.1 {
drh66518ca2013-08-01 15:09:57 +000026 # Able to parse and manage partial indices
drh1fe05372013-07-31 18:12:26 +000027 execsql {
drh721dfcf2013-08-01 04:39:17 +000028 CREATE TABLE t1(a,b,c);
drh1fe05372013-07-31 18:12:26 +000029 CREATE INDEX t1a ON t1(a) WHERE a IS NOT NULL;
30 CREATE INDEX t1b ON t1(b) WHERE b>10;
31 CREATE VIRTUAL TABLE nums USING wholenumber;
drh721dfcf2013-08-01 04:39:17 +000032 INSERT INTO t1(a,b,c)
33 SELECT CASE WHEN value%3!=0 THEN value END, value, value
drh1fe05372013-07-31 18:12:26 +000034 FROM nums WHERE value<=20;
35 SELECT count(a), count(b) FROM t1;
drh66518ca2013-08-01 15:09:57 +000036 PRAGMA integrity_check;
drh1fe05372013-07-31 18:12:26 +000037 }
drh66518ca2013-08-01 15:09:57 +000038} {14 20 ok}
drh1fe05372013-07-31 18:12:26 +000039
drh5f33f372013-10-04 00:00:12 +000040# Make sure the count(*) optimization works correctly with
41# partial indices. Ticket [a5c8ed66cae16243be6] 2013-10-03.
42#
43do_execsql_test index6-1.1.1 {
44 SELECT count(*) FROM t1;
45} {20}
46
drh66518ca2013-08-01 15:09:57 +000047# Error conditions during parsing...
48#
drh3780be12013-07-31 19:05:22 +000049do_test index6-1.2 {
50 catchsql {
drh721dfcf2013-08-01 04:39:17 +000051 CREATE INDEX bad1 ON t1(a,b) WHERE x IS NOT NULL;
drh3780be12013-07-31 19:05:22 +000052 }
drh721dfcf2013-08-01 04:39:17 +000053} {1 {no such column: x}}
drh3780be12013-07-31 19:05:22 +000054do_test index6-1.3 {
55 catchsql {
56 CREATE INDEX bad1 ON t1(a,b) WHERE EXISTS(SELECT * FROM t1);
57 }
58} {1 {subqueries prohibited in partial index WHERE clauses}}
59do_test index6-1.4 {
60 catchsql {
61 CREATE INDEX bad1 ON t1(a,b) WHERE a!=?1;
62 }
63} {1 {parameters prohibited in partial index WHERE clauses}}
64do_test index6-1.5 {
65 catchsql {
66 CREATE INDEX bad1 ON t1(a,b) WHERE a!=random();
67 }
68} {1 {functions prohibited in partial index WHERE clauses}}
69do_test index6-1.6 {
70 catchsql {
71 CREATE INDEX bad1 ON t1(a,b) WHERE a NOT LIKE 'abc%';
72 }
73} {1 {functions prohibited in partial index WHERE clauses}}
74
drh8a9789b2013-08-01 03:36:59 +000075do_test index6-1.10 {
76 execsql {
77 ANALYZE;
78 SELECT idx, stat FROM sqlite_stat1 ORDER BY idx;
79 PRAGMA integrity_check;
80 }
drh721dfcf2013-08-01 04:39:17 +000081} {{} 20 t1a {14 1} t1b {10 1} ok}
drh8a9789b2013-08-01 03:36:59 +000082
drh66518ca2013-08-01 15:09:57 +000083# STAT1 shows the partial indices have a reduced number of
84# rows.
85#
drh8a9789b2013-08-01 03:36:59 +000086do_test index6-1.11 {
87 execsql {
88 UPDATE t1 SET a=b;
89 ANALYZE;
90 SELECT idx, stat FROM sqlite_stat1 ORDER BY idx;
91 PRAGMA integrity_check;
92 }
drh721dfcf2013-08-01 04:39:17 +000093} {{} 20 t1a {20 1} t1b {10 1} ok}
drh8a9789b2013-08-01 03:36:59 +000094
95do_test index6-1.11 {
96 execsql {
97 UPDATE t1 SET a=NULL WHERE b%3!=0;
98 UPDATE t1 SET b=b+100;
99 ANALYZE;
100 SELECT idx, stat FROM sqlite_stat1 ORDER BY idx;
101 PRAGMA integrity_check;
102 }
drh721dfcf2013-08-01 04:39:17 +0000103} {{} 20 t1a {6 1} t1b {20 1} ok}
drh8a9789b2013-08-01 03:36:59 +0000104
105do_test index6-1.12 {
106 execsql {
107 UPDATE t1 SET a=CASE WHEN b%3!=0 THEN b END;
108 UPDATE t1 SET b=b-100;
109 ANALYZE;
110 SELECT idx, stat FROM sqlite_stat1 ORDER BY idx;
111 PRAGMA integrity_check;
112 }
drh721dfcf2013-08-01 04:39:17 +0000113} {{} 20 t1a {13 1} t1b {10 1} ok}
drh8a9789b2013-08-01 03:36:59 +0000114
115do_test index6-1.13 {
116 execsql {
117 DELETE FROM t1 WHERE b BETWEEN 8 AND 12;
118 ANALYZE;
119 SELECT idx, stat FROM sqlite_stat1 ORDER BY idx;
120 PRAGMA integrity_check;
121 }
drh721dfcf2013-08-01 04:39:17 +0000122} {{} 15 t1a {10 1} t1b {8 1} ok}
drh8a9789b2013-08-01 03:36:59 +0000123
124do_test index6-1.14 {
125 execsql {
126 REINDEX;
127 ANALYZE;
128 SELECT idx, stat FROM sqlite_stat1 ORDER BY idx;
129 PRAGMA integrity_check;
130 }
drh721dfcf2013-08-01 04:39:17 +0000131} {{} 15 t1a {10 1} t1b {8 1} ok}
132
133do_test index6-1.15 {
134 execsql {
135 CREATE INDEX t1c ON t1(c);
136 ANALYZE;
137 SELECT idx, stat FROM sqlite_stat1 ORDER BY idx;
138 PRAGMA integrity_check;
139 }
140} {t1a {10 1} t1b {8 1} t1c {15 1} ok}
drh3780be12013-07-31 19:05:22 +0000141
drh66518ca2013-08-01 15:09:57 +0000142# Queries use partial indices as appropriate times.
143#
144do_test index6-2.1 {
145 execsql {
146 CREATE TABLE t2(a,b);
147 INSERT INTO t2(a,b) SELECT value, value FROM nums WHERE value<1000;
dan7de2a1f2014-04-28 20:11:20 +0000148 UPDATE t2 SET a=NULL WHERE b%2==0;
drh66518ca2013-08-01 15:09:57 +0000149 CREATE INDEX t2a1 ON t2(a) WHERE a IS NOT NULL;
150 SELECT count(*) FROM t2 WHERE a IS NOT NULL;
151 }
dan7de2a1f2014-04-28 20:11:20 +0000152} {500}
drh66518ca2013-08-01 15:09:57 +0000153do_test index6-2.2 {
154 execsql {
155 EXPLAIN QUERY PLAN
156 SELECT * FROM t2 WHERE a=5;
157 }
158} {/.* TABLE t2 USING INDEX t2a1 .*/}
dan8ad169a2013-08-12 20:14:04 +0000159ifcapable stat4||stat3 {
dan7de2a1f2014-04-28 20:11:20 +0000160 execsql ANALYZE
dan3d407592013-08-07 18:42:27 +0000161 do_test index6-2.3stat4 {
drh9fe809c2013-08-06 19:18:17 +0000162 execsql {
163 EXPLAIN QUERY PLAN
164 SELECT * FROM t2 WHERE a IS NOT NULL;
165 }
166 } {/.* TABLE t2 USING INDEX t2a1 .*/}
167} else {
dan3d407592013-08-07 18:42:27 +0000168 do_test index6-2.3stat4 {
drh9fe809c2013-08-06 19:18:17 +0000169 execsql {
170 EXPLAIN QUERY PLAN
171 SELECT * FROM t2 WHERE a IS NOT NULL AND a>0;
172 }
173 } {/.* TABLE t2 USING INDEX t2a1 .*/}
174}
drh66518ca2013-08-01 15:09:57 +0000175do_test index6-2.4 {
176 execsql {
177 EXPLAIN QUERY PLAN
178 SELECT * FROM t2 WHERE a IS NULL;
179 }
180} {~/.*INDEX t2a1.*/}
181
182do_execsql_test index6-2.101 {
183 DROP INDEX t2a1;
184 UPDATE t2 SET a=b, b=b+10000;
185 SELECT b FROM t2 WHERE a=15;
186} {10015}
187do_execsql_test index6-2.102 {
188 CREATE INDEX t2a2 ON t2(a) WHERE a<100 OR a>200;
189 SELECT b FROM t2 WHERE a=15;
190 PRAGMA integrity_check;
191} {10015 ok}
192do_execsql_test index6-2.102eqp {
193 EXPLAIN QUERY PLAN
194 SELECT b FROM t2 WHERE a=15;
195} {~/.*INDEX t2a2.*/}
196do_execsql_test index6-2.103 {
197 SELECT b FROM t2 WHERE a=15 AND a<100;
198} {10015}
199do_execsql_test index6-2.103eqp {
200 EXPLAIN QUERY PLAN
201 SELECT b FROM t2 WHERE a=15 AND a<100;
202} {/.*INDEX t2a2.*/}
203do_execsql_test index6-2.104 {
204 SELECT b FROM t2 WHERE a=515 AND a>200;
205} {10515}
206do_execsql_test index6-2.104eqp {
207 EXPLAIN QUERY PLAN
208 SELECT b FROM t2 WHERE a=515 AND a>200;
209} {/.*INDEX t2a2.*/}
210
211# Partial UNIQUE indices
212#
213do_execsql_test index6-3.1 {
214 CREATE TABLE t3(a,b);
215 INSERT INTO t3 SELECT value, value FROM nums WHERE value<200;
216 UPDATE t3 SET a=999 WHERE b%5!=0;
217 CREATE UNIQUE INDEX t3a ON t3(a) WHERE a<>999;
218} {}
219do_test index6-3.2 {
220 # unable to insert a duplicate row a-value that is not 999.
221 catchsql {
222 INSERT INTO t3(a,b) VALUES(150, 'test1');
223 }
drhf9c8ce32013-11-05 13:33:55 +0000224} {1 {UNIQUE constraint failed: t3.a}}
drh66518ca2013-08-01 15:09:57 +0000225do_test index6-3.3 {
226 # can insert multiple rows with a==999 because such rows are not
227 # part of the unique index.
228 catchsql {
229 INSERT INTO t3(a,b) VALUES(999, 'test1'), (999, 'test2');
230 }
231} {0 {}}
232do_execsql_test index6-3.4 {
233 SELECT count(*) FROM t3 WHERE a=999;
234} {162}
235integrity_check index6-3.5
236
drh3bf0ac12013-08-01 16:02:40 +0000237do_execsql_test index6-4.0 {
238 VACUUM;
239 PRAGMA integrity_check;
240} {ok}
241
drh1e7d43c2013-08-02 14:18:18 +0000242# Silently ignore database name qualifiers in partial indices.
243#
244do_execsql_test index6-5.0 {
245 CREATE INDEX t3b ON t3(b) WHERE xyzzy.t3.b BETWEEN 5 AND 10;
246 /* ^^^^^-- ignored */
247 ANALYZE;
248 SELECT count(*) FROM t3 WHERE t3.b BETWEEN 5 AND 10;
249 SELECT stat+0 FROM sqlite_stat1 WHERE idx='t3b';
250} {6 6}
251
drh87744512014-04-13 19:15:49 +0000252# Test case for ticket [2ea3e9fe6379fc3f6ce7e090ce483c1a3a80d6c9] from
253# 2014-04-13: Partial index causes assertion fault on UPDATE OR REPLACE.
254#
255do_execsql_test index6-6.0 {
256 CREATE TABLE t6(a,b);
257 CREATE UNIQUE INDEX t6ab ON t1(a,b);
258 CREATE INDEX t6b ON t6(b) WHERE b=1;
259 INSERT INTO t6(a,b) VALUES(123,456);
260 SELECT * FROM t6;
261} {123 456}
262do_execsql_test index6-6.1 {
263 UPDATE OR REPLACE t6 SET b=789;
264 SELECT * FROM t6;
265} {123 789}
266do_execsql_test index6-6.2 {
267 PRAGMA integrity_check;
268} {ok}
269
drhe006a862015-02-24 18:39:00 +0000270# Test case for ticket [2326c258d02ead33d69faa63de8f4686b9b1b9d9] on
271# 2015-02-24. Any use of a partial index qualifying constraint inside
272# the ON clause of a LEFT JOIN was causing incorrect results for all
273# versions of SQLite 3.8.0 through 3.8.8.
274#
275do_execsql_test index6-7.0 {
276 CREATE TABLE t7a(x);
277 CREATE TABLE t7b(y);
278 INSERT INTO t7a(x) VALUES(1);
279 CREATE INDEX t7ax ON t7a(x) WHERE x=99;
280 PRAGMA automatic_index=OFF;
281 SELECT * FROM t7a LEFT JOIN t7b ON (x=99) ORDER BY x;
282} {1 {}}
283do_execsql_test index6-7.1 {
284 INSERT INTO t7b(y) VALUES(2);
285 SELECT * FROM t7a JOIN t7b ON (x=99) ORDER BY x;
286} {}
287do_execsql_test index6-7.2 {
288 INSERT INTO t7a(x) VALUES(99);
289 SELECT * FROM t7a LEFT JOIN t7b ON (x=99) ORDER BY x;
290} {1 {} 99 2}
291do_execsql_test index6-7.3 {
292 SELECT * FROM t7a JOIN t7b ON (x=99) ORDER BY x;
293} {99 2}
294do_execsql_test index6-7.4 {
295 EXPLAIN QUERY PLAN
296 SELECT * FROM t7a JOIN t7b ON (x=99) ORDER BY x;
297} {/USING COVERING INDEX t7ax/}
drh87744512014-04-13 19:15:49 +0000298
dan2a45cb52015-02-24 20:10:49 +0000299
300do_execsql_test index6-8.0 {
301 CREATE TABLE t8a(a,b);
302 CREATE TABLE t8b(x,y);
303 CREATE INDEX i8c ON t8b(y) WHERE x = 'value';
304
305 INSERT INTO t8a VALUES(1, 'one');
306 INSERT INTO t8a VALUES(2, 'two');
307 INSERT INTO t8a VALUES(3, 'three');
308
309 INSERT INTO t8b VALUES('value', 1);
310 INSERT INTO t8b VALUES('dummy', 2);
311 INSERT INTO t8b VALUES('value', 3);
312 INSERT INTO t8b VALUES('dummy', 4);
313} {}
314
315do_eqp_test index6-8.1 {
316 SELECT * FROM t8a LEFT JOIN t8b ON (x = 'value' AND y = a)
317} {
318 0 0 0 {SCAN TABLE t8a}
319 0 1 1 {SEARCH TABLE t8b USING INDEX i8c (y=?)}
320}
321
322do_execsql_test index6-8.2 {
323 SELECT * FROM t8a LEFT JOIN t8b ON (x = 'value' AND y = a)
324} {
325 1 one value 1
326 2 two {} {}
327 3 three value 3
328}
329
drh1fe05372013-07-31 18:12:26 +0000330finish_test