blob: 18a01dc9967e50108d14e6c6cdd703b611976345 [file] [log] [blame]
drh55ef4d92005-08-14 01:20:37 +00001# 2005 August 13
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 the LIKE and GLOB operators and
13# in particular the optimizations that occur to help those operators
14# run faster.
15#
drhc4ac22e2009-06-07 23:45:10 +000016# $Id: like.test,v 1.13 2009/06/07 23:45:11 drh Exp $
drh55ef4d92005-08-14 01:20:37 +000017
18set testdir [file dirname $argv0]
19source $testdir/tester.tcl
20
21# Create some sample data to work with.
22#
23do_test like-1.0 {
24 execsql {
25 CREATE TABLE t1(x TEXT);
26 }
27 foreach str {
28 a
29 ab
30 abc
31 abcd
32
33 acd
34 abd
35 bc
36 bcd
37
38 xyz
39 ABC
40 CDE
41 {ABC abc xyz}
42 } {
danielk19773bdca9c2006-01-17 09:35:01 +000043 db eval {INSERT INTO t1 VALUES(:str)}
drh55ef4d92005-08-14 01:20:37 +000044 }
45 execsql {
46 SELECT count(*) FROM t1;
47 }
48} {12}
49
50# Test that both case sensitive and insensitive version of LIKE work.
51#
52do_test like-1.1 {
53 execsql {
54 SELECT x FROM t1 WHERE x LIKE 'abc' ORDER BY 1;
55 }
56} {ABC abc}
57do_test like-1.2 {
58 execsql {
59 SELECT x FROM t1 WHERE x GLOB 'abc' ORDER BY 1;
60 }
61} {abc}
62do_test like-1.3 {
63 execsql {
64 SELECT x FROM t1 WHERE x LIKE 'ABC' ORDER BY 1;
65 }
66} {ABC abc}
67do_test like-1.4 {
68 execsql {
69 SELECT x FROM t1 WHERE x LIKE 'aBc' ORDER BY 1;
70 }
71} {ABC abc}
drhd2cb50b2009-01-09 21:41:17 +000072do_test like-1.5.1 {
drhc7060c42011-06-26 23:44:35 +000073 # Use sqlite3_exec() to verify fix for ticket [25ee81271091] 2011-06-26
74 sqlite3_exec db {PRAGMA case_sensitive_like=on}
75} {0 {}}
76do_test like-1.5.2 {
drh55ef4d92005-08-14 01:20:37 +000077 execsql {
drh55ef4d92005-08-14 01:20:37 +000078 SELECT x FROM t1 WHERE x LIKE 'abc' ORDER BY 1;
79 }
80} {abc}
drhc7060c42011-06-26 23:44:35 +000081do_test like-1.5.3 {
drhd2cb50b2009-01-09 21:41:17 +000082 execsql {
83 PRAGMA case_sensitive_like; -- no argument; does not change setting
84 SELECT x FROM t1 WHERE x LIKE 'abc' ORDER BY 1;
85 }
86} {abc}
drh55ef4d92005-08-14 01:20:37 +000087do_test like-1.6 {
88 execsql {
89 SELECT x FROM t1 WHERE x GLOB 'abc' ORDER BY 1;
90 }
91} {abc}
92do_test like-1.7 {
93 execsql {
94 SELECT x FROM t1 WHERE x LIKE 'ABC' ORDER BY 1;
95 }
96} {ABC}
97do_test like-1.8 {
98 execsql {
99 SELECT x FROM t1 WHERE x LIKE 'aBc' ORDER BY 1;
100 }
101} {}
102do_test like-1.9 {
103 execsql {
104 PRAGMA case_sensitive_like=off;
105 SELECT x FROM t1 WHERE x LIKE 'abc' ORDER BY 1;
106 }
107} {ABC abc}
drhd2cb50b2009-01-09 21:41:17 +0000108do_test like-1.10 {
109 execsql {
110 PRAGMA case_sensitive_like; -- No argument, does not change setting.
111 SELECT x FROM t1 WHERE x LIKE 'abc' ORDER BY 1;
112 }
113} {ABC abc}
drh55ef4d92005-08-14 01:20:37 +0000114
115# Tests of the REGEXP operator
116#
117do_test like-2.1 {
118 proc test_regexp {a b} {
119 return [regexp $a $b]
120 }
dan6bd2c732010-11-01 05:42:26 +0000121 db function regexp -argcount 2 test_regexp
drh55ef4d92005-08-14 01:20:37 +0000122 execsql {
123 SELECT x FROM t1 WHERE x REGEXP 'abc' ORDER BY 1;
124 }
125} {{ABC abc xyz} abc abcd}
126do_test like-2.2 {
127 execsql {
128 SELECT x FROM t1 WHERE x REGEXP '^abc' ORDER BY 1;
129 }
130} {abc abcd}
131
danielk1977619a3692006-06-14 08:48:25 +0000132# Tests of the MATCH operator
133#
134do_test like-2.3 {
135 proc test_match {a b} {
136 return [string match $a $b]
137 }
drhe3602be2008-09-09 12:31:33 +0000138 db function match -argcount 2 test_match
danielk1977619a3692006-06-14 08:48:25 +0000139 execsql {
140 SELECT x FROM t1 WHERE x MATCH '*abc*' ORDER BY 1;
141 }
142} {{ABC abc xyz} abc abcd}
143do_test like-2.4 {
144 execsql {
145 SELECT x FROM t1 WHERE x MATCH 'abc*' ORDER BY 1;
146 }
147} {abc abcd}
148
drh55ef4d92005-08-14 01:20:37 +0000149# For the remaining tests, we need to have the like optimizations
150# enabled.
151#
152ifcapable !like_opt {
153 finish_test
154 return
155}
156
157# This procedure executes the SQL. Then it appends to the result the
158# "sort" or "nosort" keyword (as in the cksort procedure above) then
drh7c171092013-06-03 22:08:20 +0000159# it appends the names of the table and index used.
drh55ef4d92005-08-14 01:20:37 +0000160#
161proc queryplan {sql} {
162 set ::sqlite_sort_count 0
163 set data [execsql $sql]
164 if {$::sqlite_sort_count} {set x sort} {set x nosort}
165 lappend data $x
drh7c171092013-06-03 22:08:20 +0000166 set eqp [execsql "EXPLAIN QUERY PLAN $sql"]
167 # puts eqp=$eqp
168 foreach {a b c x} $eqp {
drh8a4380d2013-06-11 02:32:50 +0000169 if {[regexp { TABLE (\w+ AS )?(\w+) USING COVERING INDEX (\w+)\y} \
drh7c171092013-06-03 22:08:20 +0000170 $x all as tab idx]} {
171 lappend data {} $idx
drh8a4380d2013-06-11 02:32:50 +0000172 } elseif {[regexp { TABLE (\w+ AS )?(\w+) USING.* INDEX (\w+)\y} \
drh7c171092013-06-03 22:08:20 +0000173 $x all as tab idx]} {
174 lappend data $tab $idx
drh8a4380d2013-06-11 02:32:50 +0000175 } elseif {[regexp { TABLE (\w+ AS )?(\w+)\y} $x all as tab]} {
drh7c171092013-06-03 22:08:20 +0000176 lappend data $tab *
177 }
178 }
179 return $data
drh55ef4d92005-08-14 01:20:37 +0000180}
181
182# Perform tests on the like optimization.
183#
184# With no index on t1.x and with case sensitivity turned off, no optimization
185# is performed.
186#
187do_test like-3.1 {
188 set sqlite_like_count 0
189 queryplan {
190 SELECT x FROM t1 WHERE x LIKE 'abc%' ORDER BY 1;
191 }
drh7c171092013-06-03 22:08:20 +0000192} {ABC {ABC abc xyz} abc abcd sort t1 *}
drh55ef4d92005-08-14 01:20:37 +0000193do_test like-3.2 {
194 set sqlite_like_count
195} {12}
196
197# With an index on t1.x and case sensitivity on, optimize completely.
198#
199do_test like-3.3 {
200 set sqlite_like_count 0
201 execsql {
202 PRAGMA case_sensitive_like=on;
203 CREATE INDEX i1 ON t1(x);
204 }
205 queryplan {
206 SELECT x FROM t1 WHERE x LIKE 'abc%' ORDER BY 1;
207 }
208} {abc abcd nosort {} i1}
209do_test like-3.4 {
210 set sqlite_like_count
211} 0
212
drh93ee23c2010-07-22 12:33:57 +0000213# The LIKE optimization still works when the RHS is a string with no
214# wildcard. Ticket [e090183531fc2747]
215#
216do_test like-3.4.2 {
217 queryplan {
218 SELECT x FROM t1 WHERE x LIKE 'a' ORDER BY 1;
219 }
220} {a nosort {} i1}
221do_test like-3.4.3 {
222 queryplan {
223 SELECT x FROM t1 WHERE x LIKE 'ab' ORDER BY 1;
224 }
225} {ab nosort {} i1}
226do_test like-3.4.4 {
227 queryplan {
228 SELECT x FROM t1 WHERE x LIKE 'abcd' ORDER BY 1;
229 }
230} {abcd nosort {} i1}
231do_test like-3.4.5 {
232 queryplan {
233 SELECT x FROM t1 WHERE x LIKE 'abcde' ORDER BY 1;
234 }
235} {nosort {} i1}
236
237
drh55ef4d92005-08-14 01:20:37 +0000238# Partial optimization when the pattern does not end in '%'
239#
240do_test like-3.5 {
241 set sqlite_like_count 0
242 queryplan {
243 SELECT x FROM t1 WHERE x LIKE 'a_c' ORDER BY 1;
244 }
245} {abc nosort {} i1}
246do_test like-3.6 {
247 set sqlite_like_count
248} 6
249do_test like-3.7 {
250 set sqlite_like_count 0
251 queryplan {
252 SELECT x FROM t1 WHERE x LIKE 'ab%d' ORDER BY 1;
253 }
254} {abcd abd nosort {} i1}
255do_test like-3.8 {
256 set sqlite_like_count
257} 4
258do_test like-3.9 {
259 set sqlite_like_count 0
260 queryplan {
261 SELECT x FROM t1 WHERE x LIKE 'a_c%' ORDER BY 1;
262 }
263} {abc abcd nosort {} i1}
264do_test like-3.10 {
265 set sqlite_like_count
266} 6
267
268# No optimization when the pattern begins with a wildcard.
269# Note that the index is still used but only for sorting.
270#
271do_test like-3.11 {
272 set sqlite_like_count 0
273 queryplan {
274 SELECT x FROM t1 WHERE x LIKE '%bcd' ORDER BY 1;
275 }
276} {abcd bcd nosort {} i1}
277do_test like-3.12 {
278 set sqlite_like_count
279} 12
280
281# No optimization for case insensitive LIKE
282#
283do_test like-3.13 {
284 set sqlite_like_count 0
drh7c171092013-06-03 22:08:20 +0000285 db eval {PRAGMA case_sensitive_like=off;}
drh55ef4d92005-08-14 01:20:37 +0000286 queryplan {
drh55ef4d92005-08-14 01:20:37 +0000287 SELECT x FROM t1 WHERE x LIKE 'abc%' ORDER BY 1;
288 }
289} {ABC {ABC abc xyz} abc abcd nosort {} i1}
290do_test like-3.14 {
291 set sqlite_like_count
292} 12
293
294# No optimization without an index.
295#
296do_test like-3.15 {
297 set sqlite_like_count 0
drh7c171092013-06-03 22:08:20 +0000298 db eval {
drh55ef4d92005-08-14 01:20:37 +0000299 PRAGMA case_sensitive_like=on;
300 DROP INDEX i1;
drh7c171092013-06-03 22:08:20 +0000301 }
302 queryplan {
drh55ef4d92005-08-14 01:20:37 +0000303 SELECT x FROM t1 WHERE x LIKE 'abc%' ORDER BY 1;
304 }
drh7c171092013-06-03 22:08:20 +0000305} {abc abcd sort t1 *}
drh55ef4d92005-08-14 01:20:37 +0000306do_test like-3.16 {
307 set sqlite_like_count
308} 12
309
310# No GLOB optimization without an index.
311#
312do_test like-3.17 {
313 set sqlite_like_count 0
314 queryplan {
315 SELECT x FROM t1 WHERE x GLOB 'abc*' ORDER BY 1;
316 }
drh7c171092013-06-03 22:08:20 +0000317} {abc abcd sort t1 *}
drh55ef4d92005-08-14 01:20:37 +0000318do_test like-3.18 {
319 set sqlite_like_count
320} 12
321
322# GLOB is optimized regardless of the case_sensitive_like setting.
323#
324do_test like-3.19 {
325 set sqlite_like_count 0
drh9da058b2011-08-17 00:40:58 +0000326 db eval {CREATE INDEX i1 ON t1(x);}
drh55ef4d92005-08-14 01:20:37 +0000327 queryplan {
drh55ef4d92005-08-14 01:20:37 +0000328 SELECT x FROM t1 WHERE x GLOB 'abc*' ORDER BY 1;
329 }
330} {abc abcd nosort {} i1}
331do_test like-3.20 {
332 set sqlite_like_count
333} 0
334do_test like-3.21 {
335 set sqlite_like_count 0
drh7c171092013-06-03 22:08:20 +0000336 db eval {PRAGMA case_sensitive_like=on;}
drh55ef4d92005-08-14 01:20:37 +0000337 queryplan {
drh55ef4d92005-08-14 01:20:37 +0000338 SELECT x FROM t1 WHERE x GLOB 'abc*' ORDER BY 1;
339 }
340} {abc abcd nosort {} i1}
341do_test like-3.22 {
342 set sqlite_like_count
343} 0
344do_test like-3.23 {
345 set sqlite_like_count 0
drh7c171092013-06-03 22:08:20 +0000346 db eval {PRAGMA case_sensitive_like=off;}
drh55ef4d92005-08-14 01:20:37 +0000347 queryplan {
drh55ef4d92005-08-14 01:20:37 +0000348 SELECT x FROM t1 WHERE x GLOB 'a[bc]d' ORDER BY 1;
349 }
350} {abd acd nosort {} i1}
351do_test like-3.24 {
352 set sqlite_like_count
353} 6
354
drh93ee23c2010-07-22 12:33:57 +0000355# GLOB optimization when there is no wildcard. Ticket [e090183531fc2747]
356#
357do_test like-3.25 {
358 queryplan {
359 SELECT x FROM t1 WHERE x GLOB 'a' ORDER BY 1;
360 }
361} {a nosort {} i1}
362do_test like-3.26 {
363 queryplan {
364 SELECT x FROM t1 WHERE x GLOB 'abcd' ORDER BY 1;
365 }
366} {abcd nosort {} i1}
367do_test like-3.27 {
368 queryplan {
369 SELECT x FROM t1 WHERE x GLOB 'abcde' ORDER BY 1;
370 }
371} {nosort {} i1}
372
373
374
drh8b3d9902005-08-19 00:14:42 +0000375# No optimization if the LHS of the LIKE is not a column name or
376# if the RHS is not a string.
377#
378do_test like-4.1 {
379 execsql {PRAGMA case_sensitive_like=on}
380 set sqlite_like_count 0
381 queryplan {
382 SELECT x FROM t1 WHERE x LIKE 'abc%' ORDER BY 1
383 }
384} {abc abcd nosort {} i1}
385do_test like-4.2 {
386 set sqlite_like_count
387} 0
388do_test like-4.3 {
389 set sqlite_like_count 0
390 queryplan {
391 SELECT x FROM t1 WHERE +x LIKE 'abc%' ORDER BY 1
392 }
393} {abc abcd nosort {} i1}
394do_test like-4.4 {
395 set sqlite_like_count
396} 12
397do_test like-4.5 {
398 set sqlite_like_count 0
399 queryplan {
400 SELECT x FROM t1 WHERE x LIKE ('ab' || 'c%') ORDER BY 1
401 }
402} {abc abcd nosort {} i1}
403do_test like-4.6 {
404 set sqlite_like_count
405} 12
406
drhd64fe2f2005-08-28 17:00:23 +0000407# Collating sequences on the index disable the LIKE optimization.
408# Or if the NOCASE collating sequence is used, the LIKE optimization
409# is enabled when case_sensitive_like is OFF.
410#
411do_test like-5.1 {
412 execsql {PRAGMA case_sensitive_like=off}
413 set sqlite_like_count 0
414 queryplan {
415 SELECT x FROM t1 WHERE x LIKE 'abc%' ORDER BY 1
416 }
417} {ABC {ABC abc xyz} abc abcd nosort {} i1}
418do_test like-5.2 {
419 set sqlite_like_count
420} 12
421do_test like-5.3 {
422 execsql {
drhc4ac22e2009-06-07 23:45:10 +0000423 CREATE TABLE t2(x TEXT COLLATE NOCASE);
drh3f4d1d12012-09-15 18:45:54 +0000424 INSERT INTO t2 SELECT * FROM t1 ORDER BY rowid;
drhd64fe2f2005-08-28 17:00:23 +0000425 CREATE INDEX i2 ON t2(x COLLATE NOCASE);
426 }
427 set sqlite_like_count 0
428 queryplan {
429 SELECT x FROM t2 WHERE x LIKE 'abc%' ORDER BY 1
430 }
431} {abc ABC {ABC abc xyz} abcd nosort {} i2}
432do_test like-5.4 {
433 set sqlite_like_count
434} 0
435do_test like-5.5 {
436 execsql {
437 PRAGMA case_sensitive_like=on;
438 }
439 set sqlite_like_count 0
440 queryplan {
441 SELECT x FROM t2 WHERE x LIKE 'abc%' ORDER BY 1
442 }
443} {abc abcd nosort {} i2}
444do_test like-5.6 {
445 set sqlite_like_count
446} 12
447do_test like-5.7 {
448 execsql {
449 PRAGMA case_sensitive_like=off;
450 }
451 set sqlite_like_count 0
452 queryplan {
453 SELECT x FROM t2 WHERE x GLOB 'abc*' ORDER BY 1
454 }
455} {abc abcd nosort {} i2}
456do_test like-5.8 {
457 set sqlite_like_count
458} 12
drh9f504ea2008-02-23 21:55:39 +0000459do_test like-5.11 {
460 execsql {PRAGMA case_sensitive_like=off}
461 set sqlite_like_count 0
462 queryplan {
463 SELECT x FROM t1 WHERE x LIKE 'ABC%' ORDER BY 1
464 }
465} {ABC {ABC abc xyz} abc abcd nosort {} i1}
466do_test like-5.12 {
467 set sqlite_like_count
468} 12
469do_test like-5.13 {
470 set sqlite_like_count 0
471 queryplan {
472 SELECT x FROM t2 WHERE x LIKE 'ABC%' ORDER BY 1
473 }
474} {abc ABC {ABC abc xyz} abcd nosort {} i2}
475do_test like-5.14 {
476 set sqlite_like_count
477} 0
478do_test like-5.15 {
479 execsql {
480 PRAGMA case_sensitive_like=on;
481 }
482 set sqlite_like_count 0
483 queryplan {
484 SELECT x FROM t2 WHERE x LIKE 'ABC%' ORDER BY 1
485 }
486} {ABC {ABC abc xyz} nosort {} i2}
487do_test like-5.16 {
488 set sqlite_like_count
489} 12
490do_test like-5.17 {
491 execsql {
492 PRAGMA case_sensitive_like=off;
493 }
494 set sqlite_like_count 0
495 queryplan {
496 SELECT x FROM t2 WHERE x GLOB 'ABC*' ORDER BY 1
497 }
498} {ABC {ABC abc xyz} nosort {} i2}
499do_test like-5.18 {
500 set sqlite_like_count
501} 12
502
503# Boundary case. The prefix for a LIKE comparison is rounded up
504# when constructing the comparison. Example: "ab" becomes "ac".
505# In other words, the last character is increased by one.
506#
507# Make sure this happens correctly when the last character is a
508# "z" and we are doing case-insensitive comparisons.
509#
510# Ticket #2959
511#
512do_test like-5.21 {
513 execsql {
514 PRAGMA case_sensitive_like=off;
515 INSERT INTO t2 VALUES('ZZ-upper-upper');
516 INSERT INTO t2 VALUES('zZ-lower-upper');
517 INSERT INTO t2 VALUES('Zz-upper-lower');
518 INSERT INTO t2 VALUES('zz-lower-lower');
519 }
520 queryplan {
521 SELECT x FROM t2 WHERE x LIKE 'zz%';
522 }
523} {zz-lower-lower zZ-lower-upper Zz-upper-lower ZZ-upper-upper nosort {} i2}
524do_test like-5.22 {
525 queryplan {
526 SELECT x FROM t2 WHERE x LIKE 'zZ%';
527 }
528} {zz-lower-lower zZ-lower-upper Zz-upper-lower ZZ-upper-upper nosort {} i2}
529do_test like-5.23 {
530 queryplan {
531 SELECT x FROM t2 WHERE x LIKE 'Zz%';
532 }
533} {zz-lower-lower zZ-lower-upper Zz-upper-lower ZZ-upper-upper nosort {} i2}
534do_test like-5.24 {
535 queryplan {
536 SELECT x FROM t2 WHERE x LIKE 'ZZ%';
537 }
538} {zz-lower-lower zZ-lower-upper Zz-upper-lower ZZ-upper-upper nosort {} i2}
539do_test like-5.25 {
drh9da058b2011-08-17 00:40:58 +0000540 db eval {
drh9f504ea2008-02-23 21:55:39 +0000541 PRAGMA case_sensitive_like=on;
drhc4ac22e2009-06-07 23:45:10 +0000542 CREATE TABLE t3(x TEXT);
drh9f504ea2008-02-23 21:55:39 +0000543 CREATE INDEX i3 ON t3(x);
544 INSERT INTO t3 VALUES('ZZ-upper-upper');
545 INSERT INTO t3 VALUES('zZ-lower-upper');
546 INSERT INTO t3 VALUES('Zz-upper-lower');
547 INSERT INTO t3 VALUES('zz-lower-lower');
drh9da058b2011-08-17 00:40:58 +0000548 }
549 queryplan {
drh9f504ea2008-02-23 21:55:39 +0000550 SELECT x FROM t3 WHERE x LIKE 'zz%';
551 }
552} {zz-lower-lower nosort {} i3}
553do_test like-5.26 {
554 queryplan {
555 SELECT x FROM t3 WHERE x LIKE 'zZ%';
556 }
557} {zZ-lower-upper nosort {} i3}
558do_test like-5.27 {
559 queryplan {
560 SELECT x FROM t3 WHERE x LIKE 'Zz%';
561 }
562} {Zz-upper-lower nosort {} i3}
563do_test like-5.28 {
564 queryplan {
565 SELECT x FROM t3 WHERE x LIKE 'ZZ%';
566 }
567} {ZZ-upper-upper nosort {} i3}
568
drhd64fe2f2005-08-28 17:00:23 +0000569
drh9c86df52007-06-11 12:56:15 +0000570# ticket #2407
571#
572# Make sure the LIKE prefix optimization does not strip off leading
573# characters of the like pattern that happen to be quote characters.
574#
575do_test like-6.1 {
576 foreach x { 'abc 'bcd 'def 'ax } {
danielk19774152e672007-09-12 17:01:45 +0000577 set x2 '[string map {' ''} $x]'
578 db eval "INSERT INTO t2 VALUES($x2)"
drh9c86df52007-06-11 12:56:15 +0000579 }
580 execsql {
581 SELECT * FROM t2 WHERE x LIKE '''a%'
582 }
583} {'abc 'ax}
drh8b3d9902005-08-19 00:14:42 +0000584
drh01495b92008-01-23 12:52:40 +0000585do_test like-7.1 {
586 execsql {
drhc4ac22e2009-06-07 23:45:10 +0000587 SELECT rowid, * FROM t1 WHERE rowid GLOB '1*' ORDER BY rowid;
drh01495b92008-01-23 12:52:40 +0000588 }
drhc4ac22e2009-06-07 23:45:10 +0000589} {1 a 10 ABC 11 CDE 12 {ABC abc xyz}}
drh01495b92008-01-23 12:52:40 +0000590
drhe3602be2008-09-09 12:31:33 +0000591# ticket #3345.
592#
593# Overloading the LIKE function with -1 for the number of arguments
594# will overload both the 2-argument and the 3-argument LIKE.
595#
596do_test like-8.1 {
597 db eval {
598 CREATE TABLE t8(x);
599 INSERT INTO t8 VALUES('abcdef');
600 INSERT INTO t8 VALUES('ghijkl');
601 INSERT INTO t8 VALUES('mnopqr');
602 SELECT 1, x FROM t8 WHERE x LIKE '%h%';
603 SELECT 2, x FROM t8 WHERE x LIKE '%h%' ESCAPE 'x';
604 }
605} {1 ghijkl 2 ghijkl}
606do_test like-8.2 {
607 proc newlike {args} {return 1} ;# Alternative LIKE is always return TRUE
608 db function like newlike ;# Uses -1 for nArg in sqlite3_create_function
609 db cache flush
610 db eval {
611 SELECT 1, x FROM t8 WHERE x LIKE '%h%';
612 SELECT 2, x FROM t8 WHERE x LIKE '%h%' ESCAPE 'x';
613 }
614} {1 ghijkl 2 ghijkl}
615do_test like-8.3 {
616 db function like -argcount 2 newlike
617 db eval {
618 SELECT 1, x FROM t8 WHERE x LIKE '%h%';
619 SELECT 2, x FROM t8 WHERE x LIKE '%h%' ESCAPE 'x';
620 }
621} {1 abcdef 1 ghijkl 1 mnopqr 2 ghijkl}
622do_test like-8.4 {
623 db function like -argcount 3 newlike
624 db eval {
625 SELECT 1, x FROM t8 WHERE x LIKE '%h%';
626 SELECT 2, x FROM t8 WHERE x LIKE '%h%' ESCAPE 'x';
627 }
628} {1 abcdef 1 ghijkl 1 mnopqr 2 abcdef 2 ghijkl 2 mnopqr}
629
630
dan6bd2c732010-11-01 05:42:26 +0000631ifcapable like_opt&&!icu {
drh5bd98ae2009-01-07 18:24:03 +0000632 # Evaluate SQL. Return the result set followed by the
633 # and the number of full-scan steps.
634 #
635 db close
636 sqlite3 db test.db
637 proc count_steps {sql} {
638 set r [db eval $sql]
639 lappend r scan [db status step] sort [db status sort]
640 }
641 do_test like-9.1 {
642 count_steps {
643 SELECT x FROM t2 WHERE x LIKE 'x%'
644 }
645 } {xyz scan 0 sort 0}
646 do_test like-9.2 {
647 count_steps {
648 SELECT x FROM t2 WHERE x LIKE '_y%'
649 }
650 } {xyz scan 19 sort 0}
651 do_test like-9.3.1 {
652 set res [sqlite3_exec_hex db {
653 SELECT x FROM t2 WHERE x LIKE '%78%25'
654 }]
655 } {0 {x xyz}}
656 ifcapable explain {
657 do_test like-9.3.2 {
658 set res [sqlite3_exec_hex db {
659 EXPLAIN QUERY PLAN SELECT x FROM t2 WHERE x LIKE '%78%25'
660 }]
661 regexp {INDEX i2} $res
662 } {1}
663 }
664 do_test like-9.4.1 {
665 sqlite3_exec_hex db {INSERT INTO t2 VALUES('%ffhello')}
666 set res [sqlite3_exec_hex db {
667 SELECT substr(x,2) AS x FROM t2 WHERE +x LIKE '%ff%25'
668 }]
669 } {0 {x hello}}
670 do_test like-9.4.2 {
671 set res [sqlite3_exec_hex db {
672 SELECT substr(x,2) AS x FROM t2 WHERE x LIKE '%ff%25'
673 }]
674 } {0 {x hello}}
675 ifcapable explain {
676 do_test like-9.4.3 {
677 set res [sqlite3_exec_hex db {
678 EXPLAIN QUERY PLAN SELECT x FROM t2 WHERE x LIKE '%ff%25'
679 }]
drh3f4d1d12012-09-15 18:45:54 +0000680 regexp {SCAN TABLE t2} $res
681 } {1}
drh5bd98ae2009-01-07 18:24:03 +0000682 }
683 do_test like-9.5.1 {
684 set res [sqlite3_exec_hex db {
685 SELECT x FROM t2 WHERE x LIKE '%fe%25'
686 }]
687 } {0 {}}
688 ifcapable explain {
689 do_test like-9.5.2 {
690 set res [sqlite3_exec_hex db {
691 EXPLAIN QUERY PLAN SELECT x FROM t2 WHERE x LIKE '%fe%25'
692 }]
693 regexp {INDEX i2} $res
694 } {1}
695 }
drh5bd98ae2009-01-07 18:24:03 +0000696
dan6bd2c732010-11-01 05:42:26 +0000697 # Do an SQL statement. Append the search count to the end of the result.
698 #
699 proc count sql {
700 set ::sqlite_search_count 0
701 set ::sqlite_like_count 0
702 return [concat [execsql $sql] scan $::sqlite_search_count \
703 like $::sqlite_like_count]
704 }
drhc4ac22e2009-06-07 23:45:10 +0000705
dan6bd2c732010-11-01 05:42:26 +0000706 # The LIKE and GLOB optimizations do not work on columns with
707 # affinity other than TEXT.
708 # Ticket #3901
709 #
710 do_test like-10.1 {
711 db close
712 sqlite3 db test.db
713 execsql {
714 CREATE TABLE t10(
715 a INTEGER PRIMARY KEY,
716 b INTEGER COLLATE nocase UNIQUE,
717 c NUMBER COLLATE nocase UNIQUE,
718 d BLOB COLLATE nocase UNIQUE,
719 e COLLATE nocase UNIQUE,
720 f TEXT COLLATE nocase UNIQUE
721 );
722 INSERT INTO t10 VALUES(1,1,1,1,1,1);
723 INSERT INTO t10 VALUES(12,12,12,12,12,12);
724 INSERT INTO t10 VALUES(123,123,123,123,123,123);
725 INSERT INTO t10 VALUES(234,234,234,234,234,234);
726 INSERT INTO t10 VALUES(345,345,345,345,345,345);
727 INSERT INTO t10 VALUES(45,45,45,45,45,45);
728 }
729 count {
drh083310d2011-01-28 01:57:41 +0000730 SELECT a FROM t10 WHERE b LIKE '12%' ORDER BY +a;
dan6bd2c732010-11-01 05:42:26 +0000731 }
732 } {12 123 scan 5 like 6}
733 do_test like-10.2 {
734 count {
drh083310d2011-01-28 01:57:41 +0000735 SELECT a FROM t10 WHERE c LIKE '12%' ORDER BY +a;
dan6bd2c732010-11-01 05:42:26 +0000736 }
737 } {12 123 scan 5 like 6}
738 do_test like-10.3 {
739 count {
drh083310d2011-01-28 01:57:41 +0000740 SELECT a FROM t10 WHERE d LIKE '12%' ORDER BY +a;
dan6bd2c732010-11-01 05:42:26 +0000741 }
742 } {12 123 scan 5 like 6}
743 do_test like-10.4 {
744 count {
drh083310d2011-01-28 01:57:41 +0000745 SELECT a FROM t10 WHERE e LIKE '12%' ORDER BY +a;
dan6bd2c732010-11-01 05:42:26 +0000746 }
747 } {12 123 scan 5 like 6}
748 do_test like-10.5 {
749 count {
drh083310d2011-01-28 01:57:41 +0000750 SELECT a FROM t10 WHERE f LIKE '12%' ORDER BY +a;
dan6bd2c732010-11-01 05:42:26 +0000751 }
drha9c18a92015-03-06 20:49:52 +0000752 } {12 123 scan 4 like 0}
dan6bd2c732010-11-01 05:42:26 +0000753 do_test like-10.6 {
754 count {
drh083310d2011-01-28 01:57:41 +0000755 SELECT a FROM t10 WHERE a LIKE '12%' ORDER BY +a;
dan6bd2c732010-11-01 05:42:26 +0000756 }
757 } {12 123 scan 5 like 6}
758 do_test like-10.10 {
759 execsql {
760 CREATE TABLE t10b(
761 a INTEGER PRIMARY KEY,
762 b INTEGER UNIQUE,
763 c NUMBER UNIQUE,
764 d BLOB UNIQUE,
765 e UNIQUE,
766 f TEXT UNIQUE
767 );
768 INSERT INTO t10b SELECT * FROM t10;
769 }
770 count {
drh083310d2011-01-28 01:57:41 +0000771 SELECT a FROM t10b WHERE b GLOB '12*' ORDER BY +a;
dan6bd2c732010-11-01 05:42:26 +0000772 }
773 } {12 123 scan 5 like 6}
774 do_test like-10.11 {
775 count {
drh083310d2011-01-28 01:57:41 +0000776 SELECT a FROM t10b WHERE c GLOB '12*' ORDER BY +a;
dan6bd2c732010-11-01 05:42:26 +0000777 }
778 } {12 123 scan 5 like 6}
779 do_test like-10.12 {
780 count {
drh083310d2011-01-28 01:57:41 +0000781 SELECT a FROM t10b WHERE d GLOB '12*' ORDER BY +a;
dan6bd2c732010-11-01 05:42:26 +0000782 }
783 } {12 123 scan 5 like 6}
784 do_test like-10.13 {
785 count {
drh083310d2011-01-28 01:57:41 +0000786 SELECT a FROM t10b WHERE e GLOB '12*' ORDER BY +a;
dan6bd2c732010-11-01 05:42:26 +0000787 }
788 } {12 123 scan 5 like 6}
789 do_test like-10.14 {
790 count {
drh083310d2011-01-28 01:57:41 +0000791 SELECT a FROM t10b WHERE f GLOB '12*' ORDER BY +a;
dan6bd2c732010-11-01 05:42:26 +0000792 }
drha9c18a92015-03-06 20:49:52 +0000793 } {12 123 scan 4 like 0}
dan6bd2c732010-11-01 05:42:26 +0000794 do_test like-10.15 {
795 count {
drh083310d2011-01-28 01:57:41 +0000796 SELECT a FROM t10b WHERE a GLOB '12*' ORDER BY +a;
dan6bd2c732010-11-01 05:42:26 +0000797 }
798 } {12 123 scan 5 like 6}
799}
drhc4ac22e2009-06-07 23:45:10 +0000800
drh8342e492010-07-22 17:49:52 +0000801# LIKE and GLOB where the default collating sequence is not appropriate
802# but an index with the appropriate collating sequence exists.
803#
804do_test like-11.0 {
805 execsql {
806 CREATE TABLE t11(
807 a INTEGER PRIMARY KEY,
808 b TEXT COLLATE nocase,
809 c TEXT COLLATE binary
810 );
811 INSERT INTO t11 VALUES(1, 'a','a');
812 INSERT INTO t11 VALUES(2, 'ab','ab');
813 INSERT INTO t11 VALUES(3, 'abc','abc');
814 INSERT INTO t11 VALUES(4, 'abcd','abcd');
815 INSERT INTO t11 VALUES(5, 'A','A');
816 INSERT INTO t11 VALUES(6, 'AB','AB');
817 INSERT INTO t11 VALUES(7, 'ABC','ABC');
818 INSERT INTO t11 VALUES(8, 'ABCD','ABCD');
819 INSERT INTO t11 VALUES(9, 'x','x');
820 INSERT INTO t11 VALUES(10, 'yz','yz');
821 INSERT INTO t11 VALUES(11, 'X','X');
822 INSERT INTO t11 VALUES(12, 'YZ','YZ');
823 SELECT count(*) FROM t11;
824 }
825} {12}
826do_test like-11.1 {
drh7c171092013-06-03 22:08:20 +0000827 db eval {PRAGMA case_sensitive_like=OFF;}
drh8342e492010-07-22 17:49:52 +0000828 queryplan {
drh8342e492010-07-22 17:49:52 +0000829 SELECT b FROM t11 WHERE b LIKE 'abc%' ORDER BY a;
830 }
831} {abc abcd ABC ABCD nosort t11 *}
832do_test like-11.2 {
drh7c171092013-06-03 22:08:20 +0000833 db eval {PRAGMA case_sensitive_like=ON;}
drh8342e492010-07-22 17:49:52 +0000834 queryplan {
drh8342e492010-07-22 17:49:52 +0000835 SELECT b FROM t11 WHERE b LIKE 'abc%' ORDER BY a;
836 }
837} {abc abcd nosort t11 *}
838do_test like-11.3 {
drh7c171092013-06-03 22:08:20 +0000839 db eval {
drh8342e492010-07-22 17:49:52 +0000840 PRAGMA case_sensitive_like=OFF;
841 CREATE INDEX t11b ON t11(b);
drh7c171092013-06-03 22:08:20 +0000842 }
843 queryplan {
drh083310d2011-01-28 01:57:41 +0000844 SELECT b FROM t11 WHERE b LIKE 'abc%' ORDER BY +a;
drh8342e492010-07-22 17:49:52 +0000845 }
846} {abc abcd ABC ABCD sort {} t11b}
847do_test like-11.4 {
drh7c171092013-06-03 22:08:20 +0000848 db eval {PRAGMA case_sensitive_like=ON;}
drh8342e492010-07-22 17:49:52 +0000849 queryplan {
drh8342e492010-07-22 17:49:52 +0000850 SELECT b FROM t11 WHERE b LIKE 'abc%' ORDER BY a;
851 }
852} {abc abcd nosort t11 *}
853do_test like-11.5 {
drh7c171092013-06-03 22:08:20 +0000854 db eval {
drh8342e492010-07-22 17:49:52 +0000855 PRAGMA case_sensitive_like=OFF;
856 DROP INDEX t11b;
857 CREATE INDEX t11bnc ON t11(b COLLATE nocase);
drh7c171092013-06-03 22:08:20 +0000858 }
859 queryplan {
drh083310d2011-01-28 01:57:41 +0000860 SELECT b FROM t11 WHERE b LIKE 'abc%' ORDER BY +a;
drh8342e492010-07-22 17:49:52 +0000861 }
862} {abc abcd ABC ABCD sort {} t11bnc}
863do_test like-11.6 {
drh7c171092013-06-03 22:08:20 +0000864 db eval {CREATE INDEX t11bb ON t11(b COLLATE binary);}
drh8342e492010-07-22 17:49:52 +0000865 queryplan {
drh083310d2011-01-28 01:57:41 +0000866 SELECT b FROM t11 WHERE b LIKE 'abc%' ORDER BY +a;
drh8342e492010-07-22 17:49:52 +0000867 }
868} {abc abcd ABC ABCD sort {} t11bnc}
869do_test like-11.7 {
drh7c171092013-06-03 22:08:20 +0000870 db eval {PRAGMA case_sensitive_like=ON;}
drh8342e492010-07-22 17:49:52 +0000871 queryplan {
drh083310d2011-01-28 01:57:41 +0000872 SELECT b FROM t11 WHERE b LIKE 'abc%' ORDER BY +a;
drh8342e492010-07-22 17:49:52 +0000873 }
874} {abc abcd sort {} t11bb}
875do_test like-11.8 {
drh7c171092013-06-03 22:08:20 +0000876 db eval {PRAGMA case_sensitive_like=OFF;}
drh8342e492010-07-22 17:49:52 +0000877 queryplan {
drh083310d2011-01-28 01:57:41 +0000878 SELECT b FROM t11 WHERE b GLOB 'abc*' ORDER BY +a;
drh8342e492010-07-22 17:49:52 +0000879 }
880} {abc abcd sort {} t11bb}
881do_test like-11.9 {
drh7c171092013-06-03 22:08:20 +0000882 db eval {
drh8342e492010-07-22 17:49:52 +0000883 CREATE INDEX t11cnc ON t11(c COLLATE nocase);
884 CREATE INDEX t11cb ON t11(c COLLATE binary);
drh7c171092013-06-03 22:08:20 +0000885 }
886 queryplan {
drh083310d2011-01-28 01:57:41 +0000887 SELECT c FROM t11 WHERE c LIKE 'abc%' ORDER BY +a;
drh8342e492010-07-22 17:49:52 +0000888 }
889} {abc abcd ABC ABCD sort {} t11cnc}
890do_test like-11.10 {
891 queryplan {
drh083310d2011-01-28 01:57:41 +0000892 SELECT c FROM t11 WHERE c GLOB 'abc*' ORDER BY +a;
drh8342e492010-07-22 17:49:52 +0000893 }
894} {abc abcd sort {} t11cb}
895
drh6ade4532014-01-16 15:31:41 +0000896# A COLLATE clause on the pattern does not change the result of a
897# LIKE operator.
898#
899do_execsql_test like-12.1 {
900 CREATE TABLE t12nc(id INTEGER, x TEXT UNIQUE COLLATE nocase);
901 INSERT INTO t12nc VALUES(1,'abcde'),(2,'uvwxy'),(3,'ABCDEF');
902 CREATE TABLE t12b(id INTEGER, x TEXT UNIQUE COLLATE binary);
903 INSERT INTO t12b VALUES(1,'abcde'),(2,'uvwxy'),(3,'ABCDEF');
904 SELECT id FROM t12nc WHERE x LIKE 'abc%' ORDER BY +id;
905} {1 3}
906do_execsql_test like-12.2 {
907 SELECT id FROM t12b WHERE x LIKE 'abc%' ORDER BY +id;
908} {1 3}
909do_execsql_test like-12.3 {
910 SELECT id FROM t12nc WHERE x LIKE 'abc%' COLLATE binary ORDER BY +id;
911} {1 3}
912do_execsql_test like-12.4 {
913 SELECT id FROM t12b WHERE x LIKE 'abc%' COLLATE binary ORDER BY +id;
914} {1 3}
915do_execsql_test like-12.5 {
916 SELECT id FROM t12nc WHERE x LIKE 'abc%' COLLATE nocase ORDER BY +id;
917} {1 3}
918do_execsql_test like-12.6 {
919 SELECT id FROM t12b WHERE x LIKE 'abc%' COLLATE nocase ORDER BY +id;
920} {1 3}
921
922# Adding a COLLATE clause to the pattern of a LIKE operator does nothing
923# to change the suitability of using an index to satisfy that LIKE
924# operator.
925#
926do_execsql_test like-12.11 {
927 EXPLAIN QUERY PLAN
928 SELECT id FROM t12nc WHERE x LIKE 'abc%' ORDER BY +id;
929} {/SEARCH/}
930do_execsql_test like-12.12 {
931 EXPLAIN QUERY PLAN
932 SELECT id FROM t12b WHERE x LIKE 'abc%' ORDER BY +id;
933} {/SCAN/}
934do_execsql_test like-12.13 {
935 EXPLAIN QUERY PLAN
936 SELECT id FROM t12nc WHERE x LIKE 'abc%' COLLATE nocase ORDER BY +id;
937} {/SEARCH/}
938do_execsql_test like-12.14 {
939 EXPLAIN QUERY PLAN
940 SELECT id FROM t12b WHERE x LIKE 'abc%' COLLATE nocase ORDER BY +id;
941} {/SCAN/}
942do_execsql_test like-12.15 {
943 EXPLAIN QUERY PLAN
944 SELECT id FROM t12nc WHERE x LIKE 'abc%' COLLATE binary ORDER BY +id;
945} {/SEARCH/}
946do_execsql_test like-12.16 {
947 EXPLAIN QUERY PLAN
948 SELECT id FROM t12b WHERE x LIKE 'abc%' COLLATE binary ORDER BY +id;
949} {/SCAN/}
950
drh5bd98ae2009-01-07 18:24:03 +0000951
drh55ef4d92005-08-14 01:20:37 +0000952finish_test