blob: e5324aee252aa3c007fedd0a0fe295711b7e4677 [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
drh169dd922017-06-26 13:57:49 +0000163 db cache flush
drh55ef4d92005-08-14 01:20:37 +0000164 set data [execsql $sql]
165 if {$::sqlite_sort_count} {set x sort} {set x nosort}
166 lappend data $x
drh7c171092013-06-03 22:08:20 +0000167 set eqp [execsql "EXPLAIN QUERY PLAN $sql"]
168 # puts eqp=$eqp
169 foreach {a b c x} $eqp {
drh8a4380d2013-06-11 02:32:50 +0000170 if {[regexp { TABLE (\w+ AS )?(\w+) USING COVERING INDEX (\w+)\y} \
drh7c171092013-06-03 22:08:20 +0000171 $x all as tab idx]} {
172 lappend data {} $idx
drh8a4380d2013-06-11 02:32:50 +0000173 } elseif {[regexp { TABLE (\w+ AS )?(\w+) USING.* INDEX (\w+)\y} \
drh7c171092013-06-03 22:08:20 +0000174 $x all as tab idx]} {
175 lappend data $tab $idx
drh8a4380d2013-06-11 02:32:50 +0000176 } elseif {[regexp { TABLE (\w+ AS )?(\w+)\y} $x all as tab]} {
drh7c171092013-06-03 22:08:20 +0000177 lappend data $tab *
178 }
179 }
180 return $data
drh55ef4d92005-08-14 01:20:37 +0000181}
182
183# Perform tests on the like optimization.
184#
185# With no index on t1.x and with case sensitivity turned off, no optimization
186# is performed.
187#
188do_test like-3.1 {
189 set sqlite_like_count 0
190 queryplan {
191 SELECT x FROM t1 WHERE x LIKE 'abc%' ORDER BY 1;
192 }
drh7c171092013-06-03 22:08:20 +0000193} {ABC {ABC abc xyz} abc abcd sort t1 *}
drh55ef4d92005-08-14 01:20:37 +0000194do_test like-3.2 {
195 set sqlite_like_count
196} {12}
197
198# With an index on t1.x and case sensitivity on, optimize completely.
199#
drh169dd922017-06-26 13:57:49 +0000200do_test like-3.3.100 {
drh55ef4d92005-08-14 01:20:37 +0000201 set sqlite_like_count 0
202 execsql {
203 PRAGMA case_sensitive_like=on;
204 CREATE INDEX i1 ON t1(x);
205 }
206 queryplan {
207 SELECT x FROM t1 WHERE x LIKE 'abc%' ORDER BY 1;
208 }
209} {abc abcd nosort {} i1}
drh1d42ea72017-07-27 20:24:29 +0000210do_test like-3.3.100.cnt {
drh55ef4d92005-08-14 01:20:37 +0000211 set sqlite_like_count
212} 0
213
drh169dd922017-06-26 13:57:49 +0000214# The like optimization works even when the pattern is a bound parameter
215#
dana50b3092017-07-15 06:35:15 +0000216# Exception: It does not work if sqlite3_prepare() is used instead of
217# sqlite3_prepare_v2(), as in that case the statement cannot be reprepared
218# after the parameter is bound.
219#
dancb0d3ba2017-07-15 08:02:10 +0000220unset -nocomplain ::likepat
dana50b3092017-07-15 06:35:15 +0000221set ::likepat abc%
222if {[permutation]!="prepare"} {
223 do_test like-3.3.102 {
224 set sqlite_like_count 0
dana50b3092017-07-15 06:35:15 +0000225 queryplan {
226 SELECT x FROM t1 WHERE x LIKE $::likepat ORDER BY 1;
227 }
228 } {abc abcd nosort {} i1}
229 do_test like-3.3.103 {
230 set sqlite_like_count
231 } 0
232}
drh169dd922017-06-26 13:57:49 +0000233
234# Except, the like optimization does not work for bound parameters if
235# the query planner stability guarantee is active.
236#
237do_test like-3.3.104 {
238 set sqlite_like_count 0
239 sqlite3_db_config db QPSG 1
240 queryplan {
241 SELECT x FROM t1 WHERE x LIKE $::likepat ORDER BY 1;
242 }
243} {abc abcd nosort {} i1}
244do_test like-3.3.105 {
245 set sqlite_like_count
246} 12
247
248# The query planner stability guarantee does not disrupt explicit patterns
249#
250do_test like-3.3.105 {
251 set sqlite_like_count 0
252 queryplan {
253 SELECT x FROM t1 WHERE x LIKE 'abc%' ORDER BY 1;
254 }
255} {abc abcd nosort {} i1}
256do_test like-3.3.106 {
257 set sqlite_like_count
258} 0
259sqlite3_db_config db QPSG 0
260
drh93ee23c2010-07-22 12:33:57 +0000261# The LIKE optimization still works when the RHS is a string with no
262# wildcard. Ticket [e090183531fc2747]
263#
264do_test like-3.4.2 {
265 queryplan {
266 SELECT x FROM t1 WHERE x LIKE 'a' ORDER BY 1;
267 }
268} {a nosort {} i1}
269do_test like-3.4.3 {
270 queryplan {
271 SELECT x FROM t1 WHERE x LIKE 'ab' ORDER BY 1;
272 }
273} {ab nosort {} i1}
274do_test like-3.4.4 {
275 queryplan {
276 SELECT x FROM t1 WHERE x LIKE 'abcd' ORDER BY 1;
277 }
278} {abcd nosort {} i1}
279do_test like-3.4.5 {
280 queryplan {
281 SELECT x FROM t1 WHERE x LIKE 'abcde' ORDER BY 1;
282 }
283} {nosort {} i1}
284
285
drh55ef4d92005-08-14 01:20:37 +0000286# Partial optimization when the pattern does not end in '%'
287#
288do_test like-3.5 {
289 set sqlite_like_count 0
290 queryplan {
291 SELECT x FROM t1 WHERE x LIKE 'a_c' ORDER BY 1;
292 }
293} {abc nosort {} i1}
294do_test like-3.6 {
295 set sqlite_like_count
296} 6
297do_test like-3.7 {
298 set sqlite_like_count 0
299 queryplan {
300 SELECT x FROM t1 WHERE x LIKE 'ab%d' ORDER BY 1;
301 }
302} {abcd abd nosort {} i1}
303do_test like-3.8 {
304 set sqlite_like_count
305} 4
306do_test like-3.9 {
307 set sqlite_like_count 0
308 queryplan {
309 SELECT x FROM t1 WHERE x LIKE 'a_c%' ORDER BY 1;
310 }
311} {abc abcd nosort {} i1}
312do_test like-3.10 {
313 set sqlite_like_count
314} 6
315
316# No optimization when the pattern begins with a wildcard.
317# Note that the index is still used but only for sorting.
318#
319do_test like-3.11 {
320 set sqlite_like_count 0
321 queryplan {
322 SELECT x FROM t1 WHERE x LIKE '%bcd' ORDER BY 1;
323 }
324} {abcd bcd nosort {} i1}
325do_test like-3.12 {
326 set sqlite_like_count
327} 12
328
329# No optimization for case insensitive LIKE
330#
331do_test like-3.13 {
332 set sqlite_like_count 0
drh7c171092013-06-03 22:08:20 +0000333 db eval {PRAGMA case_sensitive_like=off;}
drh55ef4d92005-08-14 01:20:37 +0000334 queryplan {
drh55ef4d92005-08-14 01:20:37 +0000335 SELECT x FROM t1 WHERE x LIKE 'abc%' ORDER BY 1;
336 }
337} {ABC {ABC abc xyz} abc abcd nosort {} i1}
338do_test like-3.14 {
339 set sqlite_like_count
340} 12
341
342# No optimization without an index.
343#
344do_test like-3.15 {
345 set sqlite_like_count 0
drh7c171092013-06-03 22:08:20 +0000346 db eval {
drh55ef4d92005-08-14 01:20:37 +0000347 PRAGMA case_sensitive_like=on;
348 DROP INDEX i1;
drh7c171092013-06-03 22:08:20 +0000349 }
350 queryplan {
drh55ef4d92005-08-14 01:20:37 +0000351 SELECT x FROM t1 WHERE x LIKE 'abc%' ORDER BY 1;
352 }
drh7c171092013-06-03 22:08:20 +0000353} {abc abcd sort t1 *}
drh55ef4d92005-08-14 01:20:37 +0000354do_test like-3.16 {
355 set sqlite_like_count
356} 12
357
358# No GLOB optimization without an index.
359#
360do_test like-3.17 {
361 set sqlite_like_count 0
362 queryplan {
363 SELECT x FROM t1 WHERE x GLOB 'abc*' ORDER BY 1;
364 }
drh7c171092013-06-03 22:08:20 +0000365} {abc abcd sort t1 *}
drh55ef4d92005-08-14 01:20:37 +0000366do_test like-3.18 {
367 set sqlite_like_count
368} 12
369
370# GLOB is optimized regardless of the case_sensitive_like setting.
371#
372do_test like-3.19 {
373 set sqlite_like_count 0
drh9da058b2011-08-17 00:40:58 +0000374 db eval {CREATE INDEX i1 ON t1(x);}
drh55ef4d92005-08-14 01:20:37 +0000375 queryplan {
drh55ef4d92005-08-14 01:20:37 +0000376 SELECT x FROM t1 WHERE x GLOB 'abc*' ORDER BY 1;
377 }
378} {abc abcd nosort {} i1}
379do_test like-3.20 {
380 set sqlite_like_count
381} 0
382do_test like-3.21 {
383 set sqlite_like_count 0
drh7c171092013-06-03 22:08:20 +0000384 db eval {PRAGMA case_sensitive_like=on;}
drh55ef4d92005-08-14 01:20:37 +0000385 queryplan {
drh55ef4d92005-08-14 01:20:37 +0000386 SELECT x FROM t1 WHERE x GLOB 'abc*' ORDER BY 1;
387 }
388} {abc abcd nosort {} i1}
389do_test like-3.22 {
390 set sqlite_like_count
391} 0
392do_test like-3.23 {
393 set sqlite_like_count 0
drh7c171092013-06-03 22:08:20 +0000394 db eval {PRAGMA case_sensitive_like=off;}
drh55ef4d92005-08-14 01:20:37 +0000395 queryplan {
drh55ef4d92005-08-14 01:20:37 +0000396 SELECT x FROM t1 WHERE x GLOB 'a[bc]d' ORDER BY 1;
397 }
398} {abd acd nosort {} i1}
399do_test like-3.24 {
400 set sqlite_like_count
401} 6
402
drh93ee23c2010-07-22 12:33:57 +0000403# GLOB optimization when there is no wildcard. Ticket [e090183531fc2747]
404#
405do_test like-3.25 {
406 queryplan {
407 SELECT x FROM t1 WHERE x GLOB 'a' ORDER BY 1;
408 }
409} {a nosort {} i1}
410do_test like-3.26 {
411 queryplan {
412 SELECT x FROM t1 WHERE x GLOB 'abcd' ORDER BY 1;
413 }
414} {abcd nosort {} i1}
415do_test like-3.27 {
416 queryplan {
417 SELECT x FROM t1 WHERE x GLOB 'abcde' ORDER BY 1;
418 }
419} {nosort {} i1}
420
421
422
drh8b3d9902005-08-19 00:14:42 +0000423# No optimization if the LHS of the LIKE is not a column name or
424# if the RHS is not a string.
425#
426do_test like-4.1 {
427 execsql {PRAGMA case_sensitive_like=on}
428 set sqlite_like_count 0
429 queryplan {
430 SELECT x FROM t1 WHERE x LIKE 'abc%' ORDER BY 1
431 }
432} {abc abcd nosort {} i1}
433do_test like-4.2 {
434 set sqlite_like_count
435} 0
436do_test like-4.3 {
437 set sqlite_like_count 0
438 queryplan {
439 SELECT x FROM t1 WHERE +x LIKE 'abc%' ORDER BY 1
440 }
441} {abc abcd nosort {} i1}
442do_test like-4.4 {
443 set sqlite_like_count
444} 12
445do_test like-4.5 {
446 set sqlite_like_count 0
447 queryplan {
448 SELECT x FROM t1 WHERE x LIKE ('ab' || 'c%') ORDER BY 1
449 }
450} {abc abcd nosort {} i1}
451do_test like-4.6 {
452 set sqlite_like_count
453} 12
454
drhd64fe2f2005-08-28 17:00:23 +0000455# Collating sequences on the index disable the LIKE optimization.
456# Or if the NOCASE collating sequence is used, the LIKE optimization
457# is enabled when case_sensitive_like is OFF.
458#
459do_test like-5.1 {
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.2 {
467 set sqlite_like_count
468} 12
469do_test like-5.3 {
470 execsql {
drhc4ac22e2009-06-07 23:45:10 +0000471 CREATE TABLE t2(x TEXT COLLATE NOCASE);
drh3f4d1d12012-09-15 18:45:54 +0000472 INSERT INTO t2 SELECT * FROM t1 ORDER BY rowid;
drhd64fe2f2005-08-28 17:00:23 +0000473 CREATE INDEX i2 ON t2(x COLLATE NOCASE);
474 }
475 set sqlite_like_count 0
476 queryplan {
477 SELECT x FROM t2 WHERE x LIKE 'abc%' ORDER BY 1
478 }
479} {abc ABC {ABC abc xyz} abcd nosort {} i2}
480do_test like-5.4 {
481 set sqlite_like_count
482} 0
483do_test like-5.5 {
484 execsql {
485 PRAGMA case_sensitive_like=on;
486 }
487 set sqlite_like_count 0
488 queryplan {
489 SELECT x FROM t2 WHERE x LIKE 'abc%' ORDER BY 1
490 }
491} {abc abcd nosort {} i2}
492do_test like-5.6 {
493 set sqlite_like_count
494} 12
495do_test like-5.7 {
496 execsql {
497 PRAGMA case_sensitive_like=off;
498 }
499 set sqlite_like_count 0
500 queryplan {
501 SELECT x FROM t2 WHERE x GLOB 'abc*' ORDER BY 1
502 }
503} {abc abcd nosort {} i2}
504do_test like-5.8 {
505 set sqlite_like_count
506} 12
drh9f504ea2008-02-23 21:55:39 +0000507do_test like-5.11 {
508 execsql {PRAGMA case_sensitive_like=off}
509 set sqlite_like_count 0
510 queryplan {
511 SELECT x FROM t1 WHERE x LIKE 'ABC%' ORDER BY 1
512 }
513} {ABC {ABC abc xyz} abc abcd nosort {} i1}
514do_test like-5.12 {
515 set sqlite_like_count
516} 12
517do_test like-5.13 {
518 set sqlite_like_count 0
519 queryplan {
520 SELECT x FROM t2 WHERE x LIKE 'ABC%' ORDER BY 1
521 }
522} {abc ABC {ABC abc xyz} abcd nosort {} i2}
523do_test like-5.14 {
524 set sqlite_like_count
525} 0
526do_test like-5.15 {
527 execsql {
528 PRAGMA case_sensitive_like=on;
529 }
530 set sqlite_like_count 0
531 queryplan {
532 SELECT x FROM t2 WHERE x LIKE 'ABC%' ORDER BY 1
533 }
534} {ABC {ABC abc xyz} nosort {} i2}
535do_test like-5.16 {
536 set sqlite_like_count
537} 12
538do_test like-5.17 {
539 execsql {
540 PRAGMA case_sensitive_like=off;
541 }
542 set sqlite_like_count 0
543 queryplan {
544 SELECT x FROM t2 WHERE x GLOB 'ABC*' ORDER BY 1
545 }
546} {ABC {ABC abc xyz} nosort {} i2}
547do_test like-5.18 {
548 set sqlite_like_count
549} 12
550
551# Boundary case. The prefix for a LIKE comparison is rounded up
552# when constructing the comparison. Example: "ab" becomes "ac".
553# In other words, the last character is increased by one.
554#
555# Make sure this happens correctly when the last character is a
556# "z" and we are doing case-insensitive comparisons.
557#
558# Ticket #2959
559#
560do_test like-5.21 {
561 execsql {
562 PRAGMA case_sensitive_like=off;
563 INSERT INTO t2 VALUES('ZZ-upper-upper');
564 INSERT INTO t2 VALUES('zZ-lower-upper');
565 INSERT INTO t2 VALUES('Zz-upper-lower');
566 INSERT INTO t2 VALUES('zz-lower-lower');
567 }
568 queryplan {
569 SELECT x FROM t2 WHERE x LIKE 'zz%';
570 }
571} {zz-lower-lower zZ-lower-upper Zz-upper-lower ZZ-upper-upper nosort {} i2}
572do_test like-5.22 {
573 queryplan {
574 SELECT x FROM t2 WHERE x LIKE 'zZ%';
575 }
576} {zz-lower-lower zZ-lower-upper Zz-upper-lower ZZ-upper-upper nosort {} i2}
577do_test like-5.23 {
578 queryplan {
579 SELECT x FROM t2 WHERE x LIKE 'Zz%';
580 }
581} {zz-lower-lower zZ-lower-upper Zz-upper-lower ZZ-upper-upper nosort {} i2}
582do_test like-5.24 {
583 queryplan {
584 SELECT x FROM t2 WHERE x LIKE 'ZZ%';
585 }
586} {zz-lower-lower zZ-lower-upper Zz-upper-lower ZZ-upper-upper nosort {} i2}
587do_test like-5.25 {
drh9da058b2011-08-17 00:40:58 +0000588 db eval {
drh9f504ea2008-02-23 21:55:39 +0000589 PRAGMA case_sensitive_like=on;
drhc4ac22e2009-06-07 23:45:10 +0000590 CREATE TABLE t3(x TEXT);
drh9f504ea2008-02-23 21:55:39 +0000591 CREATE INDEX i3 ON t3(x);
592 INSERT INTO t3 VALUES('ZZ-upper-upper');
593 INSERT INTO t3 VALUES('zZ-lower-upper');
594 INSERT INTO t3 VALUES('Zz-upper-lower');
595 INSERT INTO t3 VALUES('zz-lower-lower');
drh9da058b2011-08-17 00:40:58 +0000596 }
597 queryplan {
drh9f504ea2008-02-23 21:55:39 +0000598 SELECT x FROM t3 WHERE x LIKE 'zz%';
599 }
600} {zz-lower-lower nosort {} i3}
601do_test like-5.26 {
602 queryplan {
603 SELECT x FROM t3 WHERE x LIKE 'zZ%';
604 }
605} {zZ-lower-upper nosort {} i3}
606do_test like-5.27 {
607 queryplan {
608 SELECT x FROM t3 WHERE x LIKE 'Zz%';
609 }
610} {Zz-upper-lower nosort {} i3}
611do_test like-5.28 {
612 queryplan {
613 SELECT x FROM t3 WHERE x LIKE 'ZZ%';
614 }
615} {ZZ-upper-upper nosort {} i3}
616
drhd64fe2f2005-08-28 17:00:23 +0000617
drh9c86df52007-06-11 12:56:15 +0000618# ticket #2407
619#
620# Make sure the LIKE prefix optimization does not strip off leading
621# characters of the like pattern that happen to be quote characters.
622#
623do_test like-6.1 {
624 foreach x { 'abc 'bcd 'def 'ax } {
danielk19774152e672007-09-12 17:01:45 +0000625 set x2 '[string map {' ''} $x]'
626 db eval "INSERT INTO t2 VALUES($x2)"
drh9c86df52007-06-11 12:56:15 +0000627 }
628 execsql {
629 SELECT * FROM t2 WHERE x LIKE '''a%'
630 }
631} {'abc 'ax}
drh8b3d9902005-08-19 00:14:42 +0000632
drh01495b92008-01-23 12:52:40 +0000633do_test like-7.1 {
634 execsql {
drhc4ac22e2009-06-07 23:45:10 +0000635 SELECT rowid, * FROM t1 WHERE rowid GLOB '1*' ORDER BY rowid;
drh01495b92008-01-23 12:52:40 +0000636 }
drhc4ac22e2009-06-07 23:45:10 +0000637} {1 a 10 ABC 11 CDE 12 {ABC abc xyz}}
drh01495b92008-01-23 12:52:40 +0000638
drhe3602be2008-09-09 12:31:33 +0000639# ticket #3345.
640#
641# Overloading the LIKE function with -1 for the number of arguments
642# will overload both the 2-argument and the 3-argument LIKE.
643#
644do_test like-8.1 {
645 db eval {
646 CREATE TABLE t8(x);
647 INSERT INTO t8 VALUES('abcdef');
648 INSERT INTO t8 VALUES('ghijkl');
649 INSERT INTO t8 VALUES('mnopqr');
650 SELECT 1, x FROM t8 WHERE x LIKE '%h%';
651 SELECT 2, x FROM t8 WHERE x LIKE '%h%' ESCAPE 'x';
652 }
653} {1 ghijkl 2 ghijkl}
654do_test like-8.2 {
655 proc newlike {args} {return 1} ;# Alternative LIKE is always return TRUE
656 db function like newlike ;# Uses -1 for nArg in sqlite3_create_function
657 db cache flush
658 db eval {
659 SELECT 1, x FROM t8 WHERE x LIKE '%h%';
660 SELECT 2, x FROM t8 WHERE x LIKE '%h%' ESCAPE 'x';
661 }
662} {1 ghijkl 2 ghijkl}
663do_test like-8.3 {
664 db function like -argcount 2 newlike
665 db eval {
666 SELECT 1, x FROM t8 WHERE x LIKE '%h%';
667 SELECT 2, x FROM t8 WHERE x LIKE '%h%' ESCAPE 'x';
668 }
669} {1 abcdef 1 ghijkl 1 mnopqr 2 ghijkl}
670do_test like-8.4 {
671 db function like -argcount 3 newlike
672 db eval {
673 SELECT 1, x FROM t8 WHERE x LIKE '%h%';
674 SELECT 2, x FROM t8 WHERE x LIKE '%h%' ESCAPE 'x';
675 }
676} {1 abcdef 1 ghijkl 1 mnopqr 2 abcdef 2 ghijkl 2 mnopqr}
677
678
dan6bd2c732010-11-01 05:42:26 +0000679ifcapable like_opt&&!icu {
drh5bd98ae2009-01-07 18:24:03 +0000680 # Evaluate SQL. Return the result set followed by the
681 # and the number of full-scan steps.
682 #
683 db close
684 sqlite3 db test.db
685 proc count_steps {sql} {
686 set r [db eval $sql]
687 lappend r scan [db status step] sort [db status sort]
688 }
689 do_test like-9.1 {
690 count_steps {
691 SELECT x FROM t2 WHERE x LIKE 'x%'
692 }
693 } {xyz scan 0 sort 0}
694 do_test like-9.2 {
695 count_steps {
696 SELECT x FROM t2 WHERE x LIKE '_y%'
697 }
698 } {xyz scan 19 sort 0}
699 do_test like-9.3.1 {
700 set res [sqlite3_exec_hex db {
701 SELECT x FROM t2 WHERE x LIKE '%78%25'
702 }]
703 } {0 {x xyz}}
704 ifcapable explain {
705 do_test like-9.3.2 {
706 set res [sqlite3_exec_hex db {
707 EXPLAIN QUERY PLAN SELECT x FROM t2 WHERE x LIKE '%78%25'
708 }]
709 regexp {INDEX i2} $res
710 } {1}
711 }
712 do_test like-9.4.1 {
713 sqlite3_exec_hex db {INSERT INTO t2 VALUES('%ffhello')}
714 set res [sqlite3_exec_hex db {
715 SELECT substr(x,2) AS x FROM t2 WHERE +x LIKE '%ff%25'
716 }]
717 } {0 {x hello}}
718 do_test like-9.4.2 {
719 set res [sqlite3_exec_hex db {
720 SELECT substr(x,2) AS x FROM t2 WHERE x LIKE '%ff%25'
721 }]
722 } {0 {x hello}}
723 ifcapable explain {
724 do_test like-9.4.3 {
725 set res [sqlite3_exec_hex db {
726 EXPLAIN QUERY PLAN SELECT x FROM t2 WHERE x LIKE '%ff%25'
727 }]
drh3f4d1d12012-09-15 18:45:54 +0000728 regexp {SCAN TABLE t2} $res
729 } {1}
drh5bd98ae2009-01-07 18:24:03 +0000730 }
731 do_test like-9.5.1 {
732 set res [sqlite3_exec_hex db {
733 SELECT x FROM t2 WHERE x LIKE '%fe%25'
734 }]
735 } {0 {}}
736 ifcapable explain {
737 do_test like-9.5.2 {
738 set res [sqlite3_exec_hex db {
739 EXPLAIN QUERY PLAN SELECT x FROM t2 WHERE x LIKE '%fe%25'
740 }]
741 regexp {INDEX i2} $res
742 } {1}
743 }
drh5bd98ae2009-01-07 18:24:03 +0000744
dan6bd2c732010-11-01 05:42:26 +0000745 # Do an SQL statement. Append the search count to the end of the result.
746 #
747 proc count sql {
748 set ::sqlite_search_count 0
749 set ::sqlite_like_count 0
750 return [concat [execsql $sql] scan $::sqlite_search_count \
751 like $::sqlite_like_count]
752 }
drhc4ac22e2009-06-07 23:45:10 +0000753
dan6bd2c732010-11-01 05:42:26 +0000754 # The LIKE and GLOB optimizations do not work on columns with
755 # affinity other than TEXT.
756 # Ticket #3901
757 #
758 do_test like-10.1 {
759 db close
760 sqlite3 db test.db
761 execsql {
762 CREATE TABLE t10(
763 a INTEGER PRIMARY KEY,
764 b INTEGER COLLATE nocase UNIQUE,
765 c NUMBER COLLATE nocase UNIQUE,
766 d BLOB COLLATE nocase UNIQUE,
767 e COLLATE nocase UNIQUE,
768 f TEXT COLLATE nocase UNIQUE
769 );
770 INSERT INTO t10 VALUES(1,1,1,1,1,1);
771 INSERT INTO t10 VALUES(12,12,12,12,12,12);
772 INSERT INTO t10 VALUES(123,123,123,123,123,123);
773 INSERT INTO t10 VALUES(234,234,234,234,234,234);
774 INSERT INTO t10 VALUES(345,345,345,345,345,345);
775 INSERT INTO t10 VALUES(45,45,45,45,45,45);
776 }
777 count {
drh083310d2011-01-28 01:57:41 +0000778 SELECT a FROM t10 WHERE b LIKE '12%' ORDER BY +a;
dan6bd2c732010-11-01 05:42:26 +0000779 }
780 } {12 123 scan 5 like 6}
781 do_test like-10.2 {
782 count {
drh083310d2011-01-28 01:57:41 +0000783 SELECT a FROM t10 WHERE c LIKE '12%' ORDER BY +a;
dan6bd2c732010-11-01 05:42:26 +0000784 }
785 } {12 123 scan 5 like 6}
786 do_test like-10.3 {
787 count {
drh083310d2011-01-28 01:57:41 +0000788 SELECT a FROM t10 WHERE d LIKE '12%' ORDER BY +a;
dan6bd2c732010-11-01 05:42:26 +0000789 }
790 } {12 123 scan 5 like 6}
791 do_test like-10.4 {
792 count {
drh083310d2011-01-28 01:57:41 +0000793 SELECT a FROM t10 WHERE e LIKE '12%' ORDER BY +a;
dan6bd2c732010-11-01 05:42:26 +0000794 }
795 } {12 123 scan 5 like 6}
drh41d2e662015-12-01 21:23:07 +0000796 ifcapable like_match_blobs {
797 do_test like-10.5a {
798 count {
799 SELECT a FROM t10 WHERE f LIKE '12%' ORDER BY +a;
800 }
801 } {12 123 scan 4 like 0}
802 } else {
803 do_test like-10.5b {
804 count {
805 SELECT a FROM t10 WHERE f LIKE '12%' ORDER BY +a;
806 }
807 } {12 123 scan 3 like 0}
808 }
dan6bd2c732010-11-01 05:42:26 +0000809 do_test like-10.6 {
810 count {
drh083310d2011-01-28 01:57:41 +0000811 SELECT a FROM t10 WHERE a LIKE '12%' ORDER BY +a;
dan6bd2c732010-11-01 05:42:26 +0000812 }
813 } {12 123 scan 5 like 6}
814 do_test like-10.10 {
815 execsql {
816 CREATE TABLE t10b(
817 a INTEGER PRIMARY KEY,
818 b INTEGER UNIQUE,
819 c NUMBER UNIQUE,
820 d BLOB UNIQUE,
821 e UNIQUE,
822 f TEXT UNIQUE
823 );
824 INSERT INTO t10b SELECT * FROM t10;
825 }
826 count {
drh083310d2011-01-28 01:57:41 +0000827 SELECT a FROM t10b WHERE b GLOB '12*' ORDER BY +a;
dan6bd2c732010-11-01 05:42:26 +0000828 }
829 } {12 123 scan 5 like 6}
830 do_test like-10.11 {
831 count {
drh083310d2011-01-28 01:57:41 +0000832 SELECT a FROM t10b WHERE c GLOB '12*' ORDER BY +a;
dan6bd2c732010-11-01 05:42:26 +0000833 }
834 } {12 123 scan 5 like 6}
835 do_test like-10.12 {
836 count {
drh083310d2011-01-28 01:57:41 +0000837 SELECT a FROM t10b WHERE d GLOB '12*' ORDER BY +a;
dan6bd2c732010-11-01 05:42:26 +0000838 }
839 } {12 123 scan 5 like 6}
840 do_test like-10.13 {
841 count {
drh083310d2011-01-28 01:57:41 +0000842 SELECT a FROM t10b WHERE e GLOB '12*' ORDER BY +a;
dan6bd2c732010-11-01 05:42:26 +0000843 }
844 } {12 123 scan 5 like 6}
drh41d2e662015-12-01 21:23:07 +0000845 ifcapable like_match_blobs {
846 do_test like-10.14 {
847 count {
848 SELECT a FROM t10b WHERE f GLOB '12*' ORDER BY +a;
849 }
850 } {12 123 scan 4 like 0}
851 } else {
852 do_test like-10.14 {
853 count {
854 SELECT a FROM t10b WHERE f GLOB '12*' ORDER BY +a;
855 }
856 } {12 123 scan 3 like 0}
857 }
dan6bd2c732010-11-01 05:42:26 +0000858 do_test like-10.15 {
859 count {
drh083310d2011-01-28 01:57:41 +0000860 SELECT a FROM t10b WHERE a GLOB '12*' ORDER BY +a;
dan6bd2c732010-11-01 05:42:26 +0000861 }
862 } {12 123 scan 5 like 6}
863}
drhc4ac22e2009-06-07 23:45:10 +0000864
drh8342e492010-07-22 17:49:52 +0000865# LIKE and GLOB where the default collating sequence is not appropriate
866# but an index with the appropriate collating sequence exists.
867#
868do_test like-11.0 {
869 execsql {
870 CREATE TABLE t11(
871 a INTEGER PRIMARY KEY,
872 b TEXT COLLATE nocase,
873 c TEXT COLLATE binary
874 );
875 INSERT INTO t11 VALUES(1, 'a','a');
876 INSERT INTO t11 VALUES(2, 'ab','ab');
877 INSERT INTO t11 VALUES(3, 'abc','abc');
878 INSERT INTO t11 VALUES(4, 'abcd','abcd');
879 INSERT INTO t11 VALUES(5, 'A','A');
880 INSERT INTO t11 VALUES(6, 'AB','AB');
881 INSERT INTO t11 VALUES(7, 'ABC','ABC');
882 INSERT INTO t11 VALUES(8, 'ABCD','ABCD');
883 INSERT INTO t11 VALUES(9, 'x','x');
884 INSERT INTO t11 VALUES(10, 'yz','yz');
885 INSERT INTO t11 VALUES(11, 'X','X');
886 INSERT INTO t11 VALUES(12, 'YZ','YZ');
887 SELECT count(*) FROM t11;
888 }
889} {12}
890do_test like-11.1 {
drh7c171092013-06-03 22:08:20 +0000891 db eval {PRAGMA case_sensitive_like=OFF;}
drh8342e492010-07-22 17:49:52 +0000892 queryplan {
drh8342e492010-07-22 17:49:52 +0000893 SELECT b FROM t11 WHERE b LIKE 'abc%' ORDER BY a;
894 }
895} {abc abcd ABC ABCD nosort t11 *}
896do_test like-11.2 {
drh7c171092013-06-03 22:08:20 +0000897 db eval {PRAGMA case_sensitive_like=ON;}
drh8342e492010-07-22 17:49:52 +0000898 queryplan {
drh8342e492010-07-22 17:49:52 +0000899 SELECT b FROM t11 WHERE b LIKE 'abc%' ORDER BY a;
900 }
901} {abc abcd nosort t11 *}
902do_test like-11.3 {
drh7c171092013-06-03 22:08:20 +0000903 db eval {
drh8342e492010-07-22 17:49:52 +0000904 PRAGMA case_sensitive_like=OFF;
905 CREATE INDEX t11b ON t11(b);
drh7c171092013-06-03 22:08:20 +0000906 }
907 queryplan {
drh083310d2011-01-28 01:57:41 +0000908 SELECT b FROM t11 WHERE b LIKE 'abc%' ORDER BY +a;
drh8342e492010-07-22 17:49:52 +0000909 }
910} {abc abcd ABC ABCD sort {} t11b}
911do_test like-11.4 {
drh7c171092013-06-03 22:08:20 +0000912 db eval {PRAGMA case_sensitive_like=ON;}
drh8342e492010-07-22 17:49:52 +0000913 queryplan {
drh8342e492010-07-22 17:49:52 +0000914 SELECT b FROM t11 WHERE b LIKE 'abc%' ORDER BY a;
915 }
916} {abc abcd nosort t11 *}
917do_test like-11.5 {
drh7c171092013-06-03 22:08:20 +0000918 db eval {
drh8342e492010-07-22 17:49:52 +0000919 PRAGMA case_sensitive_like=OFF;
920 DROP INDEX t11b;
921 CREATE INDEX t11bnc ON t11(b COLLATE nocase);
drh7c171092013-06-03 22:08:20 +0000922 }
923 queryplan {
drh083310d2011-01-28 01:57:41 +0000924 SELECT b FROM t11 WHERE b LIKE 'abc%' ORDER BY +a;
drh8342e492010-07-22 17:49:52 +0000925 }
926} {abc abcd ABC ABCD sort {} t11bnc}
927do_test like-11.6 {
drh7c171092013-06-03 22:08:20 +0000928 db eval {CREATE INDEX t11bb ON t11(b COLLATE binary);}
drh8342e492010-07-22 17:49:52 +0000929 queryplan {
drh083310d2011-01-28 01:57:41 +0000930 SELECT b FROM t11 WHERE b LIKE 'abc%' ORDER BY +a;
drh8342e492010-07-22 17:49:52 +0000931 }
932} {abc abcd ABC ABCD sort {} t11bnc}
933do_test like-11.7 {
drh7c171092013-06-03 22:08:20 +0000934 db eval {PRAGMA case_sensitive_like=ON;}
drh8342e492010-07-22 17:49:52 +0000935 queryplan {
drh083310d2011-01-28 01:57:41 +0000936 SELECT b FROM t11 WHERE b LIKE 'abc%' ORDER BY +a;
drh8342e492010-07-22 17:49:52 +0000937 }
938} {abc abcd sort {} t11bb}
939do_test like-11.8 {
drh7c171092013-06-03 22:08:20 +0000940 db eval {PRAGMA case_sensitive_like=OFF;}
drh8342e492010-07-22 17:49:52 +0000941 queryplan {
drh083310d2011-01-28 01:57:41 +0000942 SELECT b FROM t11 WHERE b GLOB 'abc*' ORDER BY +a;
drh8342e492010-07-22 17:49:52 +0000943 }
944} {abc abcd sort {} t11bb}
945do_test like-11.9 {
drh7c171092013-06-03 22:08:20 +0000946 db eval {
drh8342e492010-07-22 17:49:52 +0000947 CREATE INDEX t11cnc ON t11(c COLLATE nocase);
948 CREATE INDEX t11cb ON t11(c COLLATE binary);
drh7c171092013-06-03 22:08:20 +0000949 }
950 queryplan {
drh083310d2011-01-28 01:57:41 +0000951 SELECT c FROM t11 WHERE c LIKE 'abc%' ORDER BY +a;
drh8342e492010-07-22 17:49:52 +0000952 }
953} {abc abcd ABC ABCD sort {} t11cnc}
954do_test like-11.10 {
955 queryplan {
drh083310d2011-01-28 01:57:41 +0000956 SELECT c FROM t11 WHERE c GLOB 'abc*' ORDER BY +a;
drh8342e492010-07-22 17:49:52 +0000957 }
958} {abc abcd sort {} t11cb}
959
drh6ade4532014-01-16 15:31:41 +0000960# A COLLATE clause on the pattern does not change the result of a
961# LIKE operator.
962#
963do_execsql_test like-12.1 {
964 CREATE TABLE t12nc(id INTEGER, x TEXT UNIQUE COLLATE nocase);
965 INSERT INTO t12nc VALUES(1,'abcde'),(2,'uvwxy'),(3,'ABCDEF');
966 CREATE TABLE t12b(id INTEGER, x TEXT UNIQUE COLLATE binary);
967 INSERT INTO t12b VALUES(1,'abcde'),(2,'uvwxy'),(3,'ABCDEF');
968 SELECT id FROM t12nc WHERE x LIKE 'abc%' ORDER BY +id;
969} {1 3}
970do_execsql_test like-12.2 {
971 SELECT id FROM t12b WHERE x LIKE 'abc%' ORDER BY +id;
972} {1 3}
973do_execsql_test like-12.3 {
974 SELECT id FROM t12nc WHERE x LIKE 'abc%' COLLATE binary ORDER BY +id;
975} {1 3}
976do_execsql_test like-12.4 {
977 SELECT id FROM t12b WHERE x LIKE 'abc%' COLLATE binary ORDER BY +id;
978} {1 3}
979do_execsql_test like-12.5 {
980 SELECT id FROM t12nc WHERE x LIKE 'abc%' COLLATE nocase ORDER BY +id;
981} {1 3}
982do_execsql_test like-12.6 {
983 SELECT id FROM t12b WHERE x LIKE 'abc%' COLLATE nocase ORDER BY +id;
984} {1 3}
985
986# Adding a COLLATE clause to the pattern of a LIKE operator does nothing
987# to change the suitability of using an index to satisfy that LIKE
988# operator.
989#
990do_execsql_test like-12.11 {
991 EXPLAIN QUERY PLAN
992 SELECT id FROM t12nc WHERE x LIKE 'abc%' ORDER BY +id;
993} {/SEARCH/}
994do_execsql_test like-12.12 {
995 EXPLAIN QUERY PLAN
996 SELECT id FROM t12b WHERE x LIKE 'abc%' ORDER BY +id;
997} {/SCAN/}
998do_execsql_test like-12.13 {
999 EXPLAIN QUERY PLAN
1000 SELECT id FROM t12nc WHERE x LIKE 'abc%' COLLATE nocase ORDER BY +id;
1001} {/SEARCH/}
1002do_execsql_test like-12.14 {
1003 EXPLAIN QUERY PLAN
1004 SELECT id FROM t12b WHERE x LIKE 'abc%' COLLATE nocase ORDER BY +id;
1005} {/SCAN/}
1006do_execsql_test like-12.15 {
1007 EXPLAIN QUERY PLAN
1008 SELECT id FROM t12nc WHERE x LIKE 'abc%' COLLATE binary ORDER BY +id;
1009} {/SEARCH/}
1010do_execsql_test like-12.16 {
1011 EXPLAIN QUERY PLAN
1012 SELECT id FROM t12b WHERE x LIKE 'abc%' COLLATE binary ORDER BY +id;
1013} {/SCAN/}
1014
drhfb397262016-01-20 14:22:41 +00001015# Ticket [https://www.sqlite.org/src/tktview/80369eddd5c94d49f7fbbcf5]
1016# 2016-01-20
1017#
1018do_execsql_test like-13.1 {
1019 SELECT char(0x304d) LIKE char(0x306d);
1020} {0}
1021do_execsql_test like-13.2 {
1022 SELECT char(0x4d) LIKE char(0x306d);
1023} {0}
1024do_execsql_test like-13.3 {
1025 SELECT char(0x304d) LIKE char(0x6d);
1026} {0}
1027do_execsql_test like-13.4 {
1028 SELECT char(0x4d) LIKE char(0x6d);
1029} {1}
1030
drh7a407072016-12-02 02:19:24 +00001031# Performance testing for patterns with many wildcards. These LIKE and GLOB
1032# patterns were quite slow with SQLite 3.15.2 and earlier.
1033#
1034do_test like-14.1 {
1035 set x [lindex [time {
1036 db one {SELECT 'aaaaaaaaaaaaaaaaaaaaaaaaaaaaaaaz'GLOB'*a*a*a*a*a*a*a*a*y'}
1037 }] 0]
1038 puts -nonewline " ($x ms - want less than 1000) "
1039 expr {$x<1000}
1040} {1}
1041ifcapable !icu {
1042 do_test like-14.2 {
1043 set x [lindex [time {
1044 db one {SELECT 'aaaaaaaaaaaaaaaaaaaaaaaaaaaaaaaz'LIKE'%a%a%a%a%a%a%a%a%y'}
1045 }] 0]
1046 puts -nonewline " ($x ms - want less than 1000) "
1047 expr {$x<1000}
1048 } {1}
1049}
drh5bd98ae2009-01-07 18:24:03 +00001050
drh9325c872017-09-27 16:51:00 +00001051ifcapable !icu {
drh1d42ea72017-07-27 20:24:29 +00001052# As of 2017-07-27 (3.21.0) the LIKE optimization works with ESCAPE as
1053# long as the ESCAPE is a single-byte literal.
1054#
1055db close
1056sqlite3 db :memory:
1057do_execsql_test like-15.100 {
1058 CREATE TABLE t15(x TEXT COLLATE nocase, y, PRIMARY KEY(x));
1059 INSERT INTO t15(x,y) VALUES
1060 ('abcde',1), ('ab%de',2), ('a_cde',3),
1061 ('uvwxy',11),('uvwx%',12),('uvwx_',13),
1062 ('_bcde',21),('%bcde',22),
1063 ('abcd_',31),('abcd%',32),
1064 ('ab%xy',41);
1065 SELECT y FROM t15 WHERE x LIKE 'ab/%d%' ESCAPE '/';
1066} {2}
1067do_execsql_test like-15.101 {
1068 EXPLAIN QUERY PLAN
1069 SELECT y FROM t15 WHERE x LIKE 'ab/%d%' ESCAPE '/';
1070} {/SEARCH/}
1071do_execsql_test like-15.102 {
1072 EXPLAIN QUERY PLAN
1073 SELECT y FROM t15 WHERE x LIKE 'ab/%d%' ESCAPE '//';
1074} {/SCAN/}
1075do_execsql_test like-15.103 {
1076 EXPLAIN QUERY PLAN
1077 SELECT y FROM t15 WHERE x LIKE 'ab/%d%' ESCAPE '';
1078} {/SCAN/}
1079do_execsql_test like-15.110 {
1080 SELECT y FROM t15 WHERE x LIKE 'abcdx%%' ESCAPE 'x';
1081} {32}
1082do_execsql_test like-15.111 {
1083 SELECT y FROM t15 WHERE x LIKE 'abx%%' ESCAPE 'x' ORDER BY +y
1084} {2 41}
1085do_execsql_test like-15.112 {
1086 EXPLAIN QUERY PLAN
1087 SELECT y FROM t15 WHERE x LIKE 'abx%%' ESCAPE 'x' ORDER BY +y
1088} {/SEARCH/}
1089do_execsql_test like-15.120 {
1090 SELECT y FROM t15 WHERE x LIKE '/%bc%' ESCAPE '/';
1091} {22}
1092do_execsql_test like-15.121 {
1093 EXPLAIN QUERY PLAN
1094 SELECT y FROM t15 WHERE x LIKE '/%bc%' ESCAPE '/';
1095} {/SEARCH/}
drh9325c872017-09-27 16:51:00 +00001096}
drh1d42ea72017-07-27 20:24:29 +00001097
drh55ef4d92005-08-14 01:20:37 +00001098finish_test