1# 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
19ifcapable !vtab {
20  finish_test
21  return
22}
23
24load_static_extension db wholenumber;
25do_test index6-1.1 {
26  # Able to parse and manage partial indices
27  execsql {
28    CREATE TABLE t1(a,b,c);
29    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;
32    INSERT INTO t1(a,b,c)
33       SELECT CASE WHEN value%3!=0 THEN value END, value, value
34         FROM nums WHERE value<=20;
35    SELECT count(a), count(b) FROM t1;
36    PRAGMA integrity_check;
37  }
38} {14 20 ok}
39
40# 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
47# Error conditions during parsing...
48#
49do_test index6-1.2 {
50  catchsql {
51    CREATE INDEX bad1 ON t1(a,b) WHERE x IS NOT NULL;
52  }
53} {1 {no such column: x}}
54do_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 {non-deterministic 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} {0 {}}
74do_execsql_test index6-1.7 {
75  DROP INDEX IF EXISTS bad1;
76}
77
78do_test index6-1.10 {
79  execsql {
80    ANALYZE;
81    SELECT idx, stat FROM sqlite_stat1 ORDER BY idx;
82    PRAGMA integrity_check;
83  }
84} {{} 20 t1a {14 1} t1b {10 1} ok}
85
86# STAT1 shows the partial indices have a reduced number of
87# rows.
88#
89do_test index6-1.11 {
90  execsql {
91    UPDATE t1 SET a=b;
92    ANALYZE;
93    SELECT idx, stat FROM sqlite_stat1 ORDER BY idx;
94    PRAGMA integrity_check;
95  }
96} {{} 20 t1a {20 1} t1b {10 1} ok}
97
98do_test index6-1.11 {
99  execsql {
100    UPDATE t1 SET a=NULL WHERE b%3!=0;
101    UPDATE t1 SET b=b+100;
102    ANALYZE;
103    SELECT idx, stat FROM sqlite_stat1 ORDER BY idx;
104    PRAGMA integrity_check;
105  }
106} {{} 20 t1a {6 1} t1b {20 1} ok}
107
108do_test index6-1.12 {
109  execsql {
110    UPDATE t1 SET a=CASE WHEN b%3!=0 THEN b END;
111    UPDATE t1 SET b=b-100;
112    ANALYZE;
113    SELECT idx, stat FROM sqlite_stat1 ORDER BY idx;
114    PRAGMA integrity_check;
115  }
116} {{} 20 t1a {13 1} t1b {10 1} ok}
117
118do_test index6-1.13 {
119  execsql {
120    DELETE FROM t1 WHERE b BETWEEN 8 AND 12;
121    ANALYZE;
122    SELECT idx, stat FROM sqlite_stat1 ORDER BY idx;
123    PRAGMA integrity_check;
124  }
125} {{} 15 t1a {10 1} t1b {8 1} ok}
126
127do_test index6-1.14 {
128  execsql {
129    REINDEX;
130    ANALYZE;
131    SELECT idx, stat FROM sqlite_stat1 ORDER BY idx;
132    PRAGMA integrity_check;
133  }
134} {{} 15 t1a {10 1} t1b {8 1} ok}
135
136do_test index6-1.15 {
137  execsql {
138    CREATE INDEX t1c ON t1(c);
139    ANALYZE;
140    SELECT idx, stat FROM sqlite_stat1 ORDER BY idx;
141    PRAGMA integrity_check;
142  }
143} {t1a {10 1} t1b {8 1} t1c {15 1} ok}
144
145# Queries use partial indices as appropriate times.
146#
147do_test index6-2.1 {
148  execsql {
149    CREATE TABLE t2(a,b);
150    INSERT INTO t2(a,b) SELECT value, value FROM nums WHERE value<1000;
151    UPDATE t2 SET a=NULL WHERE b%2==0;
152    CREATE INDEX t2a1 ON t2(a) WHERE a IS NOT NULL;
153    SELECT count(*) FROM t2 WHERE a IS NOT NULL;
154  }
155} {500}
156do_test index6-2.2 {
157  execsql {
158    EXPLAIN QUERY PLAN
159    SELECT * FROM t2 WHERE a=5;
160  }
161} {/.* TABLE t2 USING INDEX t2a1 .*/}
162ifcapable stat4 {
163  execsql ANALYZE
164  do_test index6-2.3stat4 {
165    execsql {
166      EXPLAIN QUERY PLAN
167      SELECT * FROM t2 WHERE a IS NOT NULL;
168    }
169  } {/.* TABLE t2 USING INDEX t2a1 .*/}
170} else {
171  do_test index6-2.3stat4 {
172    execsql {
173      EXPLAIN QUERY PLAN
174      SELECT * FROM t2 WHERE a IS NOT NULL AND a>0;
175    }
176  } {/.* TABLE t2 USING INDEX t2a1 .*/}
177}
178do_test index6-2.4 {
179  execsql {
180    EXPLAIN QUERY PLAN
181    SELECT * FROM t2 WHERE a IS NULL;
182  }
183} {~/.*INDEX t2a1.*/}
184
185do_execsql_test index6-2.101 {
186  DROP INDEX t2a1;
187  UPDATE t2 SET a=b, b=b+10000;
188  SELECT b FROM t2 WHERE a=15;
189} {10015}
190do_execsql_test index6-2.102 {
191  CREATE INDEX t2a2 ON t2(a) WHERE a<100 OR a>200;
192  SELECT b FROM t2 WHERE a=15;
193  PRAGMA integrity_check;
194} {10015 ok}
195do_execsql_test index6-2.102eqp {
196  EXPLAIN QUERY PLAN
197  SELECT b FROM t2 WHERE a=15;
198} {~/.*INDEX t2a2.*/}
199do_execsql_test index6-2.103 {
200  SELECT b FROM t2 WHERE a=15 AND a<100;
201} {10015}
202do_execsql_test index6-2.103eqp {
203  EXPLAIN QUERY PLAN
204  SELECT b FROM t2 WHERE a=15 AND a<100;
205} {/.*INDEX t2a2.*/}
206do_execsql_test index6-2.104 {
207  SELECT b FROM t2 WHERE a=515 AND a>200;
208} {10515}
209do_execsql_test index6-2.104eqp {
210  EXPLAIN QUERY PLAN
211  SELECT b FROM t2 WHERE a=515 AND a>200;
212} {/.*INDEX t2a2.*/}
213
214# Partial UNIQUE indices
215#
216do_execsql_test index6-3.1 {
217  CREATE TABLE t3(a,b);
218  INSERT INTO t3 SELECT value, value FROM nums WHERE value<200;
219  UPDATE t3 SET a=999 WHERE b%5!=0;
220  CREATE UNIQUE INDEX t3a ON t3(a) WHERE a<>999;
221} {}
222do_test index6-3.2 {
223  # unable to insert a duplicate row a-value that is not 999.
224  catchsql {
225    INSERT INTO t3(a,b) VALUES(150, 'test1');
226  }
227} {1 {UNIQUE constraint failed: t3.a}}
228do_test index6-3.3 {
229  # can insert multiple rows with a==999 because such rows are not
230  # part of the unique index.
231  catchsql {
232    INSERT INTO t3(a,b) VALUES(999, 'test1'), (999, 'test2');
233  }
234} {0 {}}
235do_execsql_test index6-3.4 {
236  SELECT count(*) FROM t3 WHERE a=999;
237} {162}
238integrity_check index6-3.5
239
240do_execsql_test index6-4.0 {
241  VACUUM;
242  PRAGMA integrity_check;
243} {ok}
244
245# Silently ignore database name qualifiers in partial indices.
246#
247do_execsql_test index6-5.0 {
248  CREATE INDEX t3b ON t3(b) WHERE xyzzy.t3.b BETWEEN 5 AND 10;
249                               /* ^^^^^-- ignored */
250  ANALYZE;
251  SELECT count(*) FROM t3 WHERE t3.b BETWEEN 5 AND 10;
252  SELECT stat+0 FROM sqlite_stat1 WHERE idx='t3b';
253} {6 6}
254
255# Test case for ticket [2ea3e9fe6379fc3f6ce7e090ce483c1a3a80d6c9] from
256# 2014-04-13: Partial index causes assertion fault on UPDATE OR REPLACE.
257#
258do_execsql_test index6-6.0 {
259  CREATE TABLE t6(a,b);
260  CREATE UNIQUE INDEX t6ab ON t1(a,b);
261  CREATE INDEX t6b ON t6(b) WHERE b=1;
262  INSERT INTO t6(a,b) VALUES(123,456);
263  SELECT * FROM t6;
264} {123 456}
265do_execsql_test index6-6.1 {
266  UPDATE OR REPLACE t6 SET b=789;
267  SELECT * FROM t6;
268} {123 789}
269do_execsql_test index6-6.2 {
270  PRAGMA integrity_check;
271} {ok}
272
273# Test case for ticket [2326c258d02ead33d69faa63de8f4686b9b1b9d9] on
274# 2015-02-24.  Any use of a partial index qualifying constraint inside
275# the ON clause of a LEFT JOIN was causing incorrect results for all
276# versions of SQLite 3.8.0 through 3.8.8.
277#
278do_execsql_test index6-7.0 {
279  CREATE TABLE t7a(x);
280  CREATE TABLE t7b(y);
281  INSERT INTO t7a(x) VALUES(1);
282  CREATE INDEX t7ax ON t7a(x) WHERE x=99;
283  PRAGMA automatic_index=OFF;
284  SELECT * FROM t7a LEFT JOIN t7b ON (x=99) ORDER BY x;
285} {1 {}}
286do_execsql_test index6-7.1 {
287  INSERT INTO t7b(y) VALUES(2);
288  SELECT * FROM t7a JOIN t7b ON (x=99) ORDER BY x;
289} {}
290do_execsql_test index6-7.2 {
291  INSERT INTO t7a(x) VALUES(99);
292  SELECT * FROM t7a LEFT JOIN t7b ON (x=99) ORDER BY x;
293} {1 {} 99 2}
294do_execsql_test index6-7.3 {
295  SELECT * FROM t7a JOIN t7b ON (x=99) ORDER BY x;
296} {99 2}
297do_execsql_test index6-7.4 {
298  EXPLAIN QUERY PLAN
299  SELECT * FROM t7a JOIN t7b ON (x=99) ORDER BY x;
300} {/USING COVERING INDEX t7ax/}
301
302
303do_execsql_test index6-8.0 {
304  CREATE TABLE t8a(a,b);
305  CREATE TABLE t8b(x,y);
306  CREATE INDEX i8c ON t8b(y) WHERE x = 'value';
307
308  INSERT INTO t8a VALUES(1, 'one');
309  INSERT INTO t8a VALUES(2, 'two');
310  INSERT INTO t8a VALUES(3, 'three');
311
312  INSERT INTO t8b VALUES('value', 1);
313  INSERT INTO t8b VALUES('dummy', 2);
314  INSERT INTO t8b VALUES('value', 3);
315  INSERT INTO t8b VALUES('dummy', 4);
316} {}
317
318do_eqp_test index6-8.1 {
319  SELECT * FROM t8a LEFT JOIN t8b ON (x = 'value' AND y = a)
320} {
321  QUERY PLAN
322  |--SCAN TABLE t8a
323  `--SEARCH TABLE t8b USING INDEX i8c (y=?)
324}
325
326do_execsql_test index6-8.2 {
327  SELECT * FROM t8a LEFT JOIN t8b ON (x = 'value' AND y = a)
328} {
329  1 one value 1
330  2 two {} {}
331  3 three value 3
332}
333
334# 2015-06-11.  Assertion fault found by AFL
335#
336do_execsql_test index6-9.1 {
337  CREATE TABLE t9(a int, b int, c int);
338  CREATE INDEX t9ca ON t9(c,a) WHERE a in (10,12,20);
339  INSERT INTO t9 VALUES(1,1,9),(10,2,35),(11,15,82),(20,19,5),(NULL,7,3);
340  UPDATE t9 SET b=c WHERE a in (10,12,20);
341  SELECT a,b,c,'|' FROM t9 ORDER BY a;
342} {{} 7 3 | 1 1 9 | 10 35 35 | 11 15 82 | 20 5 5 |}
343do_execsql_test index6-9.2 {
344  DROP TABLE t9;
345  CREATE TABLE t9(a int, b int, c int, PRIMARY KEY(a)) WITHOUT ROWID;
346  CREATE INDEX t9ca ON t9(c,a) WHERE a in (10,12,20);
347  INSERT INTO t9 VALUES(1,1,9),(10,2,35),(11,15,82),(20,19,5);
348  UPDATE t9 SET b=c WHERE a in (10,12,20);
349  SELECT a,b,c,'|' FROM t9 ORDER BY a;
350} {1 1 9 | 10 35 35 | 11 15 82 | 20 5 5 |}
351
352# AND-connected terms in the WHERE clause of a partial index
353#
354do_execsql_test index6-10.1 {
355  CREATE TABLE t10(a,b,c,d,e INTEGER PRIMARY KEY);
356  INSERT INTO t10 VALUES
357    (1,2,3,4,5),
358    (2,3,4,5,6),
359    (3,4,5,6,7),
360    (1,2,3,8,9);
361  CREATE INDEX t10x ON t10(d) WHERE a=1 AND b=2 AND c=3;
362  SELECT e FROM t10 WHERE a=1 AND b=2 AND c=3 ORDER BY d;
363} {5 9}
364do_execsql_test index6-10.1eqp {
365  EXPLAIN QUERY PLAN
366  SELECT e FROM t10 WHERE a=1 AND b=2 AND c=3 ORDER BY d;
367} {/USING INDEX t10x/}
368do_execsql_test index6-10.2 {
369  SELECT e FROM t10 WHERE c=3 AND 2=b AND a=1 ORDER BY d DESC;
370} {9 5}
371do_execsql_test index6-10.2eqp {
372  EXPLAIN QUERY PLAN
373  SELECT e FROM t10 WHERE c=3 AND 2=b AND a=1 ORDER BY d DESC;
374} {/USING INDEX t10x/}
375do_execsql_test index6-10.3 {
376  SELECT e FROM t10 WHERE a=1 AND b=2 ORDER BY d DESC;
377} {9 5}
378do_execsql_test index6-10.3eqp {
379  EXPLAIN QUERY PLAN
380  SELECT e FROM t10 WHERE a=1 AND b=2 ORDER BY d DESC;
381} {~/USING INDEX t10x/}
382
383# A partial index will be used for a full table scan, where possible
384do_execsql_test index6-11.1 {
385  CREATE TABLE t11(a,b,c);
386  CREATE INDEX t11x ON t11(a) WHERE b<>99;
387  EXPLAIN QUERY PLAN SELECT a FROM t11 WHERE b<>99;
388} {/USING INDEX t11x/}
389do_execsql_test index6-11.2 {
390  EXPLAIN QUERY PLAN SELECT a FROM t11 WHERE b<>99 AND c<>98;
391} {/USING INDEX t11x/}
392
393# 2018-12-08
394# Ticket https://www.sqlite.org/src/info/1d958d90596593a7
395# NOT IN operator fails when using a partial index.
396#
397do_execsql_test index6-12.1 {
398  DROP TABLE IF EXISTS t1;
399  DROP TABLE IF EXISTS t2;
400  CREATE TABLE t1(a,b);
401  INSERT INTO t1 VALUES(1,1);
402  INSERT INTO t1 VALUES(2,2);
403  CREATE TABLE t2(x);
404  INSERT INTO t2 VALUES(1);
405  INSERT INTO t2 VALUES(2);
406  SELECT 'one', * FROM t2 WHERE x NOT IN (SELECT a FROM t1);
407  CREATE INDEX t1a ON t1(a) WHERE b=1;
408  SELECT 'two', * FROM t2 WHERE x NOT IN (SELECT a FROM t1);
409} {}
410do_execsql_test index6-12.2 {
411  SELECT x FROM t2 WHERE x IN (SELECT a FROM t1) ORDER BY +x;
412} {1 2}
413
414# 2019-05-04
415# Ticket https://www.sqlite.org/src/tktview/5c6955204c392ae763a95
416# Theorem prover error
417#
418do_execsql_test index6-13.1 {
419  DROP TABLE IF EXISTS t0;
420  CREATE TABLE t0(c0);
421  CREATE INDEX index_0 ON t0(c0) WHERE c0 NOT NULL;
422  INSERT INTO t0(c0) VALUES (NULL);
423  SELECT * FROM t0 WHERE c0 OR 1;
424} {{}}
425
426# 2019-05-11
427# Ticket https://sqlite.org/src/tktview/8025674847
428reset_db
429do_execsql_test index6-14.1 {
430  CREATE TABLE IF NOT EXISTS t0 (c0, c1);
431  CREATE INDEX IF NOT EXISTS i0 ON t0(c0, c1) WHERE c0 NOT NULL;
432  INSERT INTO t0(c0, c1) VALUES(NULL, 'row');
433  SELECT * FROM t0 WHERE t0.c0 IS NOT 1;
434} {{} row}
435
436do_execsql_test index6-14.2 {
437  SELECT * FROM t0 WHERE CASE c0 WHEN 0 THEN 0 ELSE 1 END;
438} {{} row}
439
440# 2019-08-30
441# Ticket https://www.sqlite.org/src/info/a6408d42b9f44462
442# Ticket https://www.sqlite.org/src/info/fba33c8b1df6a915
443# https://sqlite.org/src/info/bac716244fddac1fe841
444#
445do_execsql_test index6-15.1 {
446  DROP TABLE t0;
447  CREATE TABLE t0(c0);
448  INSERT INTO t0(c0) VALUES (NULL);
449  CREATE INDEX i0 ON t0(1) WHERE c0 NOT NULL;
450  SELECT 1 FROM t0 WHERE (t0.c0 IS FALSE) IS FALSE;
451} {1}
452do_execsql_test index6-15.2 {
453  SELECT 1 FROM t0 WHERE (t0.c0 IS FALSE) BETWEEN FALSE AND TRUE;
454} {1}
455do_execsql_test index6-15.3 {
456  SELECT 1 FROM t0 WHERE TRUE BETWEEN (t0.c0 IS FALSE) AND TRUE;
457} {1}
458do_execsql_test index6-15.4 {
459  SELECT 1 FROM t0 WHERE FALSE BETWEEN FALSE AND (t0.c0 IS FALSE);
460} {1}
461do_execsql_test index6-15.5 {
462  SELECT 1 FROM t0 WHERE (c0 IS FALSE) IN (FALSE);
463} {1}
464
465# 2019-09-03
466# Ticket https://sqlite.org/src/info/767a8cbc6d20bd68
467do_execsql_test index6-16.1 {
468  DROP TABLE t0;
469  CREATE TABLE t0(c0 COLLATE NOCASE, c1);
470  CREATE INDEX i0 ON t0(0) WHERE c0 >= c1;
471  INSERT INTO t0 VALUES('a', 'B');
472  SELECT c1 <= c0, c0 >= c1 FROM t0;
473} {1 0}
474do_execsql_test index6-16.2 {
475  SELECT 2 FROM t0 WHERE c0 >= c1;
476} {}
477do_execsql_test index6-16.3 {
478  SELECT 3 FROM t0 WHERE c1 <= c0;
479} {3}
480
481# 2019-11-02
482# Ticket https://sqlite.org/src/tktview/a9efb42811fa41ee286e8
483db close
484sqlite3 db :memory:
485do_execsql_test index6-17.1 {
486  CREATE TABLE t0(c0);
487  CREATE INDEX i0 ON t0(0) WHERE c0 GLOB c0;
488  INSERT INTO t0 VALUES (0);
489  CREATE UNIQUE INDEX i1 ON t0(0);
490  PRAGMA integrity_check;
491} {ok}
492do_execsql_test index6-17.2 {
493  CREATE UNIQUE INDEX i2 ON t0(0);
494  REPLACE INTO t0 VALUES(0);
495  PRAGMA integrity_check;
496} {ok}
497do_execsql_test index6-17.3 {
498  SELECT COUNT(*) FROM t0 WHERE t0.c0 GLOB t0.c0;
499} {1}
500
501finish_test
502