blob: e18cbd8d38e40cc98529618e0d3b6bdb79ce919e [file] [log] [blame]
drh47991422015-08-31 15:58:06 +00001# 2015-08-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# This file implements regression tests for SQLite library. The
12# focus of this file is testing indexes on expressions.
13#
14
15set testdir [file dirname $argv0]
16source $testdir/tester.tcl
17
18do_execsql_test indexexpr1-100 {
19 CREATE TABLE t1(a,b,c);
20 INSERT INTO t1(a,b,c)
drh390b88a2015-08-31 18:13:01 +000021 /* 123456789 123456789 123456789 123456789 123456789 123456789 */
drh1d85e402015-08-31 17:34:41 +000022 VALUES('In_the_beginning_was_the_Word',1,1),
23 ('and_the_Word_was_with_God',1,2),
24 ('and_the_Word_was_God',1,3),
25 ('The_same_was_in_the_beginning_with_God',2,1),
26 ('All_things_were_made_by_him',3,1),
27 ('and_without_him_was_not_any_thing_made_that_was_made',3,2);
drh47991422015-08-31 15:58:06 +000028 CREATE INDEX t1a1 ON t1(substr(a,1,12));
29} {}
30do_execsql_test indexexpr1-110 {
drh1d85e402015-08-31 17:34:41 +000031 SELECT b, c, '|' FROM t1 WHERE substr(a,1,12)=='and_the_Word' ORDER BY b, c;
drh47991422015-08-31 15:58:06 +000032} {1 2 | 1 3 |}
33do_execsql_test indexexpr1-110eqp {
34 EXPLAIN QUERY PLAN
drh1d85e402015-08-31 17:34:41 +000035 SELECT b, c, '|' FROM t1 WHERE substr(a,1,12)=='and_the_Word' ORDER BY b, c;
drh47991422015-08-31 15:58:06 +000036} {/USING INDEX t1a1/}
37do_execsql_test indexexpr1-120 {
drh1d85e402015-08-31 17:34:41 +000038 SELECT b, c, '|' FROM t1 WHERE 'and_the_Word'==substr(a,1,12) ORDER BY b, c;
drh47991422015-08-31 15:58:06 +000039} {1 2 | 1 3 |}
40do_execsql_test indexexpr1-120eqp {
41 EXPLAIN QUERY PLAN
drh1d85e402015-08-31 17:34:41 +000042 SELECT b, c, '|' FROM t1 WHERE 'and_the_Word'==substr(a,1,12) ORDER BY b, c;
drh47991422015-08-31 15:58:06 +000043} {/USING INDEX t1a1/}
44
drh1d85e402015-08-31 17:34:41 +000045do_execsql_test indexexpr1-130 {
46 CREATE INDEX t1ba ON t1(b,substr(a,2,3),c);
47 SELECT c FROM t1 WHERE b=1 AND substr(a,2,3)='nd_' ORDER BY c;
48} {2 3}
49do_execsql_test indexexpr1-130eqp {
50 EXPLAIN QUERY PLAN
51 SELECT c FROM t1 WHERE b=1 AND substr(a,2,3)='nd_' ORDER BY c;
52} {/USING INDEX t1ba/}
53
54do_execsql_test indexexpr1-140 {
55 SELECT rowid, substr(a,b,3), '|' FROM t1 ORDER BY 2;
56} {1 In_ | 2 and | 3 and | 6 d_w | 4 he_ | 5 l_t |}
57do_execsql_test indexexpr1-141 {
58 CREATE INDEX t1abx ON t1(substr(a,b,3));
59 SELECT rowid FROM t1 WHERE substr(a,b,3)<='and' ORDER BY +rowid;
60} {1 2 3}
61do_execsql_test indexexpr1-141eqp {
62 EXPLAIN QUERY PLAN
63 SELECT rowid FROM t1 WHERE substr(a,b,3)<='and' ORDER BY +rowid;
64} {/USING INDEX t1abx/}
65do_execsql_test indexexpr1-142 {
66 SELECT rowid FROM t1 WHERE +substr(a,b,3)<='and' ORDER BY +rowid;
67} {1 2 3}
68do_execsql_test indexexpr1-150 {
69 SELECT rowid FROM t1 WHERE substr(a,b,3) IN ('and','l_t','xyz')
70 ORDER BY +rowid;
71} {2 3 5}
72do_execsql_test indexexpr1-150eqp {
73 EXPLAIN QUERY PLAN
74 SELECT rowid FROM t1 WHERE substr(a,b,3) IN ('and','l_t','xyz')
75 ORDER BY +rowid;
76} {/USING INDEX t1abx/}
77
drh390b88a2015-08-31 18:13:01 +000078do_execsql_test indexexpr1-160 {
79 ALTER TABLE t1 ADD COLUMN d;
80 UPDATE t1 SET d=length(a);
81 CREATE INDEX t1a2 ON t1(SUBSTR(a, 27, 3)) WHERE d>=29;
82 SELECT rowid, b, c FROM t1
83 WHERE substr(a,27,3)=='ord' AND d>=29;
84} {1 1 1}
85do_execsql_test indexexpr1-160eqp {
86 EXPLAIN QUERY PLAN
87 SELECT rowid, b, c FROM t1
88 WHERE substr(a,27,3)=='ord' AND d>=29;
89} {/USING INDEX t1a2/}
90
drhdae26fe2015-09-24 18:47:59 +000091# ORDER BY using an indexed expression
92#
93do_execsql_test indexexpr1-170 {
94 CREATE INDEX t1alen ON t1(length(a));
95 SELECT length(a) FROM t1 ORDER BY length(a);
96} {20 25 27 29 38 52}
97do_execsql_test indexexpr1-170eqp {
98 EXPLAIN QUERY PLAN
99 SELECT length(a) FROM t1 ORDER BY length(a);
100} {/SCAN TABLE t1 USING INDEX t1alen/}
101do_execsql_test indexexpr1-171 {
102 SELECT length(a) FROM t1 ORDER BY length(a) DESC;
103} {52 38 29 27 25 20}
104do_execsql_test indexexpr1-171eqp {
105 EXPLAIN QUERY PLAN
106 SELECT length(a) FROM t1 ORDER BY length(a) DESC;
107} {/SCAN TABLE t1 USING INDEX t1alen/}
drh390b88a2015-08-31 18:13:01 +0000108
drh1d85e402015-08-31 17:34:41 +0000109do_execsql_test indexexpr1-200 {
110 DROP TABLE t1;
111 CREATE TABLE t1(id ANY PRIMARY KEY, a,b,c) WITHOUT ROWID;
112 INSERT INTO t1(id,a,b,c)
113 VALUES(1,'In_the_beginning_was_the_Word',1,1),
114 (2,'and_the_Word_was_with_God',1,2),
115 (3,'and_the_Word_was_God',1,3),
116 (4,'The_same_was_in_the_beginning_with_God',2,1),
117 (5,'All_things_were_made_by_him',3,1),
118 (6,'and_without_him_was_not_any_thing_made_that_was_made',3,2);
119 CREATE INDEX t1a1 ON t1(substr(a,1,12));
120} {}
121do_execsql_test indexexpr1-210 {
122 SELECT b, c, '|' FROM t1 WHERE substr(a,1,12)=='and_the_Word' ORDER BY b, c;
123} {1 2 | 1 3 |}
124do_execsql_test indexexpr1-210eqp {
125 EXPLAIN QUERY PLAN
126 SELECT b, c, '|' FROM t1 WHERE substr(a,1,12)=='and_the_Word' ORDER BY b, c;
127} {/USING INDEX t1a1/}
128do_execsql_test indexexpr1-220 {
129 SELECT b, c, '|' FROM t1 WHERE 'and_the_Word'==substr(a,1,12) ORDER BY b, c;
130} {1 2 | 1 3 |}
131do_execsql_test indexexpr1-220eqp {
132 EXPLAIN QUERY PLAN
133 SELECT b, c, '|' FROM t1 WHERE 'and_the_Word'==substr(a,1,12) ORDER BY b, c;
134} {/USING INDEX t1a1/}
135
136do_execsql_test indexexpr1-230 {
137 CREATE INDEX t1ba ON t1(b,substr(a,2,3),c);
138 SELECT c FROM t1 WHERE b=1 AND substr(a,2,3)='nd_' ORDER BY c;
139} {2 3}
140do_execsql_test indexexpr1-230eqp {
141 EXPLAIN QUERY PLAN
142 SELECT c FROM t1 WHERE b=1 AND substr(a,2,3)='nd_' ORDER BY c;
143} {/USING INDEX t1ba/}
144
145do_execsql_test indexexpr1-240 {
146 SELECT id, substr(a,b,3), '|' FROM t1 ORDER BY 2;
147} {1 In_ | 2 and | 3 and | 6 d_w | 4 he_ | 5 l_t |}
148do_execsql_test indexexpr1-241 {
149 CREATE INDEX t1abx ON t1(substr(a,b,3));
150 SELECT id FROM t1 WHERE substr(a,b,3)<='and' ORDER BY +id;
151} {1 2 3}
152do_execsql_test indexexpr1-241eqp {
153 EXPLAIN QUERY PLAN
154 SELECT id FROM t1 WHERE substr(a,b,3)<='and' ORDER BY +id;
155} {/USING INDEX t1abx/}
156do_execsql_test indexexpr1-242 {
157 SELECT id FROM t1 WHERE +substr(a,b,3)<='and' ORDER BY +id;
158} {1 2 3}
159do_execsql_test indexexpr1-250 {
160 SELECT id FROM t1 WHERE substr(a,b,3) IN ('and','l_t','xyz')
161 ORDER BY +id;
162} {2 3 5}
163do_execsql_test indexexpr1-250eqp {
164 EXPLAIN QUERY PLAN
165 SELECT id FROM t1 WHERE substr(a,b,3) IN ('and','l_t','xyz')
166 ORDER BY +id;
167} {/USING INDEX t1abx/}
168
drh390b88a2015-08-31 18:13:01 +0000169do_execsql_test indexexpr1-260 {
170 ALTER TABLE t1 ADD COLUMN d;
171 UPDATE t1 SET d=length(a);
172 CREATE INDEX t1a2 ON t1(SUBSTR(a, 27, 3)) WHERE d>=29;
173 SELECT id, b, c FROM t1
174 WHERE substr(a,27,3)=='ord' AND d>=29;
175} {1 1 1}
176do_execsql_test indexexpr1-260eqp {
177 EXPLAIN QUERY PLAN
178 SELECT id, b, c FROM t1
179 WHERE substr(a,27,3)=='ord' AND d>=29;
180} {/USING INDEX t1a2/}
181
182
drh1d85e402015-08-31 17:34:41 +0000183do_catchsql_test indexexpr1-300 {
184 CREATE TABLE t2(a,b,c);
185 CREATE INDEX t2x1 ON t2(a,b+random());
186} {1 {non-deterministic functions prohibited in index expressions}}
187do_catchsql_test indexexpr1-301 {
188 CREATE INDEX t2x1 ON t2(a+julianday('now'));
189} {1 {non-deterministic functions prohibited in index expressions}}
190do_catchsql_test indexexpr1-310 {
191 CREATE INDEX t2x2 ON t2(a,b+(SELECT 15));
192} {1 {subqueries prohibited in index expressions}}
drh390b88a2015-08-31 18:13:01 +0000193do_catchsql_test indexexpr1-320 {
194 CREATE TABLE e1(x,y,UNIQUE(y,substr(x,1,5)));
195} {1 {expressions prohibited in PRIMARY KEY and UNIQUE constraints}}
196do_catchsql_test indexexpr1-330 {
197 CREATE TABLE e1(x,y,PRIMARY KEY(y,substr(x,1,5)));
198} {1 {expressions prohibited in PRIMARY KEY and UNIQUE constraints}}
199do_catchsql_test indexexpr1-331 {
200 CREATE TABLE e1(x,y,PRIMARY KEY(y,substr(x,1,5))) WITHOUT ROWID;
201} {1 {expressions prohibited in PRIMARY KEY and UNIQUE constraints}}
202do_catchsql_test indexexpr1-340 {
203 CREATE TABLE e1(x,y,FOREIGN KEY(substr(y,1,5)) REFERENCES t1);
204} {1 {near "(": syntax error}}
drh47991422015-08-31 15:58:06 +0000205
drh8b576422015-08-31 23:09:42 +0000206do_execsql_test indexexpr1-400 {
207 CREATE TABLE t3(a,b,c);
208 WITH RECURSIVE c(x) AS (VALUES(1) UNION SELECT x+1 FROM c WHERE x<30)
209 INSERT INTO t3(a,b,c)
210 SELECT x, printf('ab%04xyz',x), random() FROM c;
211 CREATE UNIQUE INDEX t3abc ON t3(CAST(a AS text), b, substr(c,1,3));
212 SELECT a FROM t3 WHERE CAST(a AS text)<='10' ORDER BY +a;
213} {1 10}
214do_catchsql_test indexexpr1-410 {
215 INSERT INTO t3 SELECT * FROM t3 WHERE rowid=10;
216} {1 {UNIQUE constraint failed: index 't3abc'}}
217
drh0b8d2552015-09-05 22:36:07 +0000218do_execsql_test indexexpr1-500 {
219 CREATE TABLE t5(a);
220 CREATE TABLE cnt(x);
221 WITH RECURSIVE
222 c(x) AS (VALUES(1) UNION ALL SELECT x+1 FROM c WHERE x<5)
223 INSERT INTO cnt(x) SELECT x FROM c;
224 INSERT INTO t5(a) SELECT printf('abc%03dxyz',x) FROM cnt;
225 CREATE INDEX t5ax ON t5( substr(a,4,3) );
226} {}
227do_execsql_test indexexpr1-510 {
228 -- The use of the "k" alias in the WHERE clause is technically
229 -- illegal, but SQLite allows it for historical reasons. In this
230 -- test and the next, verify that "k" can be used by the t5ax index
231 SELECT substr(a,4,3) AS k FROM cnt, t5 WHERE k=printf('%03d',x);
232} {001 002 003 004 005}
233do_execsql_test indexexpr1-510eqp {
234 EXPLAIN QUERY PLAN
235 SELECT substr(a,4,3) AS k FROM cnt, t5 WHERE k=printf('%03d',x);
236} {/USING INDEX t5ax/}
237
drhe63e8a62015-09-18 18:09:28 +0000238# Skip-scan on an indexed expression
239#
240do_execsql_test indexexpr1-600 {
241 DROP TABLE IF EXISTS t4;
242 CREATE TABLE t4(a,b,c,d,e,f,g,h,i);
243 CREATE INDEX t4all ON t4(a,b,c<d,e,f,i,h);
244 INSERT INTO t4 VALUES(1,2,3,4,5,6,7,8,9);
245 ANALYZE;
246 DELETE FROM sqlite_stat1;
247 INSERT INTO sqlite_stat1
248 VALUES('t4','t4all','600000 160000 40000 10000 2000 600 100 40 10');
249 ANALYZE sqlite_master;
250 SELECT i FROM t4 WHERE e=5;
251} {9}
252
drhc5de2d02015-09-24 12:19:17 +0000253# Indexed expressions on both sides of an == in a WHERE clause.
254#
drh72694432015-09-24 11:26:45 +0000255do_execsql_test indexexpr1-700 {
256 DROP TABLE IF EXISTS t7;
257 CREATE TABLE t7(a,b,c);
258 INSERT INTO t7(a,b,c) VALUES(1,2,2),('abc','def','def'),(4,5,6);
259 CREATE INDEX t7b ON t7(+b);
260 CREATE INDEX t7c ON t7(+c);
261 SELECT *, '|' FROM t7 WHERE +b=+c ORDER BY +a;
262} {1 2 2 | abc def def |}
drhc5de2d02015-09-24 12:19:17 +0000263do_execsql_test indexexpr1-710 {
264 CREATE TABLE t71(a,b,c);
265 CREATE INDEX t71bc ON t71(b+c);
266 CREATE TABLE t72(x,y,z);
267 CREATE INDEX t72yz ON t72(y+z);
268 INSERT INTO t71(a,b,c) VALUES(1,11,2),(2,7,15),(3,5,4);
269 INSERT INTO t72(x,y,z) VALUES(1,10,3),(2,8,14),(3,9,9);
270 SELECT a, x, '|' FROM t71, t72
271 WHERE b+c=y+z
272 ORDER BY +a, +x;
273} {1 1 | 2 2 |}
drh0b8d2552015-09-05 22:36:07 +0000274
drhdae26fe2015-09-24 18:47:59 +0000275# Collating sequences on indexes of expressions
276#
277do_execsql_test indexexpr1-800 {
278 DROP TABLE IF EXISTS t8;
279 CREATE TABLE t8(a INTEGER PRIMARY KEY, b TEXT);
280 CREATE UNIQUE INDEX t8bx ON t8(substr(b,2,4) COLLATE nocase);
281 INSERT INTO t8(a,b) VALUES(1,'Alice'),(2,'Bartholemew'),(3,'Cynthia');
282 SELECT * FROM t8 WHERE substr(b,2,4)='ARTH' COLLATE nocase;
283} {2 Bartholemew}
284do_catchsql_test indexexpr1-810 {
285 INSERT INTO t8(a,b) VALUES(4,'BARTHMERE');
286} {1 {UNIQUE constraint failed: index 't8bx'}}
287do_catchsql_test indexexpr1-820 {
288 DROP INDEX t8bx;
289 CREATE UNIQUE INDEX t8bx ON t8(substr(b,2,4) COLLATE rtrim);
290 INSERT INTO t8(a,b) VALUES(4,'BARTHMERE');
291} {0 {}}
292
293
294
drh47991422015-08-31 15:58:06 +0000295finish_test