xref: /sqlite-3.40.0/test/like.test (revision 4b8035e6)
1# 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#
16# $Id: like.test,v 1.13 2009/06/07 23:45:11 drh Exp $
17
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  } {
43    db eval {INSERT INTO t1 VALUES(:str)}
44  }
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}
72do_test like-1.5.1 {
73  # 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 {
77  execsql {
78    SELECT x FROM t1 WHERE x LIKE 'abc' ORDER BY 1;
79  }
80} {abc}
81do_test like-1.5.3 {
82  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}
87do_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}
108do_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}
114
115# Tests of the REGEXP operator
116#
117do_test like-2.1 {
118  proc test_regexp {a b} {
119    return [regexp $a $b]
120  }
121  db function regexp -argcount 2 test_regexp
122  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
132# Tests of the MATCH operator
133#
134do_test like-2.3 {
135  proc test_match {a b} {
136    return [string match $a $b]
137  }
138  db function match -argcount 2 test_match
139  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
149# 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
159# it appends the names of the table and index used.
160#
161proc queryplan {sql} {
162  set ::sqlite_sort_count 0
163  db cache flush
164  set data [execsql $sql]
165  if {$::sqlite_sort_count} {set x sort} {set x nosort}
166  lappend data $x
167  set eqp [execsql "EXPLAIN QUERY PLAN $sql"]
168  # puts eqp=$eqp
169  foreach {a b c x} $eqp {
170    if {[regexp { TABLE (\w+ AS )?(\w+) USING COVERING INDEX (\w+)\y} \
171        $x all as tab idx]} {
172      lappend data {} $idx
173    } elseif {[regexp { TABLE (\w+ AS )?(\w+) USING.* INDEX (\w+)\y} \
174        $x all as tab idx]} {
175      lappend data $tab $idx
176    } elseif {[regexp { TABLE (\w+ AS )?(\w+)\y} $x all as tab]} {
177      lappend data $tab *
178    }
179  }
180  return $data
181}
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  }
193} {ABC {ABC abc xyz} abc abcd sort t1 *}
194do_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#
200do_test like-3.3.100 {
201  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}
210do_test like-3.3.101 {
211  set sqlite_like_count
212} 0
213
214# The like optimization works even when the pattern is a bound parameter
215#
216do_test like-3.3.102 {
217  set sqlite_like_count 0
218  unset -nocomplain ::likepat
219  set ::likepat abc%
220  queryplan {
221    SELECT x FROM t1 WHERE x LIKE $::likepat ORDER BY 1;
222  }
223} {abc abcd nosort {} i1}
224do_test like-3.3.103 {
225  set sqlite_like_count
226} 0
227
228# Except, the like optimization does not work for bound parameters if
229# the query planner stability guarantee is active.
230#
231do_test like-3.3.104 {
232  set sqlite_like_count 0
233  sqlite3_db_config db QPSG 1
234  queryplan {
235    SELECT x FROM t1 WHERE x LIKE $::likepat ORDER BY 1;
236  }
237} {abc abcd nosort {} i1}
238do_test like-3.3.105 {
239  set sqlite_like_count
240} 12
241
242# The query planner stability guarantee does not disrupt explicit patterns
243#
244do_test like-3.3.105 {
245  set sqlite_like_count 0
246  queryplan {
247    SELECT x FROM t1 WHERE x LIKE 'abc%' ORDER BY 1;
248  }
249} {abc abcd nosort {} i1}
250do_test like-3.3.106 {
251  set sqlite_like_count
252} 0
253sqlite3_db_config db QPSG 0
254
255# The LIKE optimization still works when the RHS is a string with no
256# wildcard.  Ticket [e090183531fc2747]
257#
258do_test like-3.4.2 {
259  queryplan {
260    SELECT x FROM t1 WHERE x LIKE 'a' ORDER BY 1;
261  }
262} {a nosort {} i1}
263do_test like-3.4.3 {
264  queryplan {
265    SELECT x FROM t1 WHERE x LIKE 'ab' ORDER BY 1;
266  }
267} {ab nosort {} i1}
268do_test like-3.4.4 {
269  queryplan {
270    SELECT x FROM t1 WHERE x LIKE 'abcd' ORDER BY 1;
271  }
272} {abcd nosort {} i1}
273do_test like-3.4.5 {
274  queryplan {
275    SELECT x FROM t1 WHERE x LIKE 'abcde' ORDER BY 1;
276  }
277} {nosort {} i1}
278
279
280# Partial optimization when the pattern does not end in '%'
281#
282do_test like-3.5 {
283  set sqlite_like_count 0
284  queryplan {
285    SELECT x FROM t1 WHERE x LIKE 'a_c' ORDER BY 1;
286  }
287} {abc nosort {} i1}
288do_test like-3.6 {
289  set sqlite_like_count
290} 6
291do_test like-3.7 {
292  set sqlite_like_count 0
293  queryplan {
294    SELECT x FROM t1 WHERE x LIKE 'ab%d' ORDER BY 1;
295  }
296} {abcd abd nosort {} i1}
297do_test like-3.8 {
298  set sqlite_like_count
299} 4
300do_test like-3.9 {
301  set sqlite_like_count 0
302  queryplan {
303    SELECT x FROM t1 WHERE x LIKE 'a_c%' ORDER BY 1;
304  }
305} {abc abcd nosort {} i1}
306do_test like-3.10 {
307  set sqlite_like_count
308} 6
309
310# No optimization when the pattern begins with a wildcard.
311# Note that the index is still used but only for sorting.
312#
313do_test like-3.11 {
314  set sqlite_like_count 0
315  queryplan {
316    SELECT x FROM t1 WHERE x LIKE '%bcd' ORDER BY 1;
317  }
318} {abcd bcd nosort {} i1}
319do_test like-3.12 {
320  set sqlite_like_count
321} 12
322
323# No optimization for case insensitive LIKE
324#
325do_test like-3.13 {
326  set sqlite_like_count 0
327  db eval {PRAGMA case_sensitive_like=off;}
328  queryplan {
329    SELECT x FROM t1 WHERE x LIKE 'abc%' ORDER BY 1;
330  }
331} {ABC {ABC abc xyz} abc abcd nosort {} i1}
332do_test like-3.14 {
333  set sqlite_like_count
334} 12
335
336# No optimization without an index.
337#
338do_test like-3.15 {
339  set sqlite_like_count 0
340  db eval {
341    PRAGMA case_sensitive_like=on;
342    DROP INDEX i1;
343  }
344  queryplan {
345    SELECT x FROM t1 WHERE x LIKE 'abc%' ORDER BY 1;
346  }
347} {abc abcd sort t1 *}
348do_test like-3.16 {
349  set sqlite_like_count
350} 12
351
352# No GLOB optimization without an index.
353#
354do_test like-3.17 {
355  set sqlite_like_count 0
356  queryplan {
357    SELECT x FROM t1 WHERE x GLOB 'abc*' ORDER BY 1;
358  }
359} {abc abcd sort t1 *}
360do_test like-3.18 {
361  set sqlite_like_count
362} 12
363
364# GLOB is optimized regardless of the case_sensitive_like setting.
365#
366do_test like-3.19 {
367  set sqlite_like_count 0
368  db eval {CREATE INDEX i1 ON t1(x);}
369  queryplan {
370    SELECT x FROM t1 WHERE x GLOB 'abc*' ORDER BY 1;
371  }
372} {abc abcd nosort {} i1}
373do_test like-3.20 {
374  set sqlite_like_count
375} 0
376do_test like-3.21 {
377  set sqlite_like_count 0
378  db eval {PRAGMA case_sensitive_like=on;}
379  queryplan {
380    SELECT x FROM t1 WHERE x GLOB 'abc*' ORDER BY 1;
381  }
382} {abc abcd nosort {} i1}
383do_test like-3.22 {
384  set sqlite_like_count
385} 0
386do_test like-3.23 {
387  set sqlite_like_count 0
388  db eval {PRAGMA case_sensitive_like=off;}
389  queryplan {
390    SELECT x FROM t1 WHERE x GLOB 'a[bc]d' ORDER BY 1;
391  }
392} {abd acd nosort {} i1}
393do_test like-3.24 {
394  set sqlite_like_count
395} 6
396
397# GLOB optimization when there is no wildcard.  Ticket [e090183531fc2747]
398#
399do_test like-3.25 {
400  queryplan {
401    SELECT x FROM t1 WHERE x GLOB 'a' ORDER BY 1;
402  }
403} {a nosort {} i1}
404do_test like-3.26 {
405  queryplan {
406    SELECT x FROM t1 WHERE x GLOB 'abcd' ORDER BY 1;
407  }
408} {abcd nosort {} i1}
409do_test like-3.27 {
410  queryplan {
411    SELECT x FROM t1 WHERE x GLOB 'abcde' ORDER BY 1;
412  }
413} {nosort {} i1}
414
415
416
417# No optimization if the LHS of the LIKE is not a column name or
418# if the RHS is not a string.
419#
420do_test like-4.1 {
421  execsql {PRAGMA case_sensitive_like=on}
422  set sqlite_like_count 0
423  queryplan {
424    SELECT x FROM t1 WHERE x LIKE 'abc%' ORDER BY 1
425  }
426} {abc abcd nosort {} i1}
427do_test like-4.2 {
428  set sqlite_like_count
429} 0
430do_test like-4.3 {
431  set sqlite_like_count 0
432  queryplan {
433    SELECT x FROM t1 WHERE +x LIKE 'abc%' ORDER BY 1
434  }
435} {abc abcd nosort {} i1}
436do_test like-4.4 {
437  set sqlite_like_count
438} 12
439do_test like-4.5 {
440  set sqlite_like_count 0
441  queryplan {
442    SELECT x FROM t1 WHERE x LIKE ('ab' || 'c%') ORDER BY 1
443  }
444} {abc abcd nosort {} i1}
445do_test like-4.6 {
446  set sqlite_like_count
447} 12
448
449# Collating sequences on the index disable the LIKE optimization.
450# Or if the NOCASE collating sequence is used, the LIKE optimization
451# is enabled when case_sensitive_like is OFF.
452#
453do_test like-5.1 {
454  execsql {PRAGMA case_sensitive_like=off}
455  set sqlite_like_count 0
456  queryplan {
457    SELECT x FROM t1 WHERE x LIKE 'abc%' ORDER BY 1
458  }
459} {ABC {ABC abc xyz} abc abcd nosort {} i1}
460do_test like-5.2 {
461  set sqlite_like_count
462} 12
463do_test like-5.3 {
464  execsql {
465    CREATE TABLE t2(x TEXT COLLATE NOCASE);
466    INSERT INTO t2 SELECT * FROM t1 ORDER BY rowid;
467    CREATE INDEX i2 ON t2(x COLLATE NOCASE);
468  }
469  set sqlite_like_count 0
470  queryplan {
471    SELECT x FROM t2 WHERE x LIKE 'abc%' ORDER BY 1
472  }
473} {abc ABC {ABC abc xyz} abcd nosort {} i2}
474do_test like-5.4 {
475  set sqlite_like_count
476} 0
477do_test like-5.5 {
478  execsql {
479    PRAGMA case_sensitive_like=on;
480  }
481  set sqlite_like_count 0
482  queryplan {
483    SELECT x FROM t2 WHERE x LIKE 'abc%' ORDER BY 1
484  }
485} {abc abcd nosort {} i2}
486do_test like-5.6 {
487  set sqlite_like_count
488} 12
489do_test like-5.7 {
490  execsql {
491    PRAGMA case_sensitive_like=off;
492  }
493  set sqlite_like_count 0
494  queryplan {
495    SELECT x FROM t2 WHERE x GLOB 'abc*' ORDER BY 1
496  }
497} {abc abcd nosort {} i2}
498do_test like-5.8 {
499  set sqlite_like_count
500} 12
501do_test like-5.11 {
502  execsql {PRAGMA case_sensitive_like=off}
503  set sqlite_like_count 0
504  queryplan {
505    SELECT x FROM t1 WHERE x LIKE 'ABC%' ORDER BY 1
506  }
507} {ABC {ABC abc xyz} abc abcd nosort {} i1}
508do_test like-5.12 {
509  set sqlite_like_count
510} 12
511do_test like-5.13 {
512  set sqlite_like_count 0
513  queryplan {
514    SELECT x FROM t2 WHERE x LIKE 'ABC%' ORDER BY 1
515  }
516} {abc ABC {ABC abc xyz} abcd nosort {} i2}
517do_test like-5.14 {
518  set sqlite_like_count
519} 0
520do_test like-5.15 {
521  execsql {
522    PRAGMA case_sensitive_like=on;
523  }
524  set sqlite_like_count 0
525  queryplan {
526    SELECT x FROM t2 WHERE x LIKE 'ABC%' ORDER BY 1
527  }
528} {ABC {ABC abc xyz} nosort {} i2}
529do_test like-5.16 {
530  set sqlite_like_count
531} 12
532do_test like-5.17 {
533  execsql {
534    PRAGMA case_sensitive_like=off;
535  }
536  set sqlite_like_count 0
537  queryplan {
538    SELECT x FROM t2 WHERE x GLOB 'ABC*' ORDER BY 1
539  }
540} {ABC {ABC abc xyz} nosort {} i2}
541do_test like-5.18 {
542  set sqlite_like_count
543} 12
544
545# Boundary case.  The prefix for a LIKE comparison is rounded up
546# when constructing the comparison.  Example:  "ab" becomes "ac".
547# In other words, the last character is increased by one.
548#
549# Make sure this happens correctly when the last character is a
550# "z" and we are doing case-insensitive comparisons.
551#
552# Ticket #2959
553#
554do_test like-5.21 {
555  execsql {
556    PRAGMA case_sensitive_like=off;
557    INSERT INTO t2 VALUES('ZZ-upper-upper');
558    INSERT INTO t2 VALUES('zZ-lower-upper');
559    INSERT INTO t2 VALUES('Zz-upper-lower');
560    INSERT INTO t2 VALUES('zz-lower-lower');
561  }
562  queryplan {
563    SELECT x FROM t2 WHERE x LIKE 'zz%';
564  }
565} {zz-lower-lower zZ-lower-upper Zz-upper-lower ZZ-upper-upper nosort {} i2}
566do_test like-5.22 {
567  queryplan {
568    SELECT x FROM t2 WHERE x LIKE 'zZ%';
569  }
570} {zz-lower-lower zZ-lower-upper Zz-upper-lower ZZ-upper-upper nosort {} i2}
571do_test like-5.23 {
572  queryplan {
573    SELECT x FROM t2 WHERE x LIKE 'Zz%';
574  }
575} {zz-lower-lower zZ-lower-upper Zz-upper-lower ZZ-upper-upper nosort {} i2}
576do_test like-5.24 {
577  queryplan {
578    SELECT x FROM t2 WHERE x LIKE 'ZZ%';
579  }
580} {zz-lower-lower zZ-lower-upper Zz-upper-lower ZZ-upper-upper nosort {} i2}
581do_test like-5.25 {
582  db eval {
583    PRAGMA case_sensitive_like=on;
584    CREATE TABLE t3(x TEXT);
585    CREATE INDEX i3 ON t3(x);
586    INSERT INTO t3 VALUES('ZZ-upper-upper');
587    INSERT INTO t3 VALUES('zZ-lower-upper');
588    INSERT INTO t3 VALUES('Zz-upper-lower');
589    INSERT INTO t3 VALUES('zz-lower-lower');
590  }
591  queryplan {
592    SELECT x FROM t3 WHERE x LIKE 'zz%';
593  }
594} {zz-lower-lower nosort {} i3}
595do_test like-5.26 {
596  queryplan {
597    SELECT x FROM t3 WHERE x LIKE 'zZ%';
598  }
599} {zZ-lower-upper nosort {} i3}
600do_test like-5.27 {
601  queryplan {
602    SELECT x FROM t3 WHERE x LIKE 'Zz%';
603  }
604} {Zz-upper-lower nosort {} i3}
605do_test like-5.28 {
606  queryplan {
607    SELECT x FROM t3 WHERE x LIKE 'ZZ%';
608  }
609} {ZZ-upper-upper nosort {} i3}
610
611
612# ticket #2407
613#
614# Make sure the LIKE prefix optimization does not strip off leading
615# characters of the like pattern that happen to be quote characters.
616#
617do_test like-6.1 {
618  foreach x { 'abc 'bcd 'def 'ax } {
619    set x2 '[string map {' ''} $x]'
620    db eval "INSERT INTO t2 VALUES($x2)"
621  }
622  execsql {
623    SELECT * FROM t2 WHERE x LIKE '''a%'
624  }
625} {'abc 'ax}
626
627do_test like-7.1 {
628  execsql {
629    SELECT rowid, * FROM t1 WHERE rowid GLOB '1*' ORDER BY rowid;
630  }
631} {1 a 10 ABC 11 CDE 12 {ABC abc xyz}}
632
633# ticket #3345.
634#
635# Overloading the LIKE function with -1 for the number of arguments
636# will overload both the 2-argument and the 3-argument LIKE.
637#
638do_test like-8.1 {
639  db eval {
640    CREATE TABLE t8(x);
641    INSERT INTO t8 VALUES('abcdef');
642    INSERT INTO t8 VALUES('ghijkl');
643    INSERT INTO t8 VALUES('mnopqr');
644    SELECT 1, x FROM t8 WHERE x LIKE '%h%';
645    SELECT 2, x FROM t8 WHERE x LIKE '%h%' ESCAPE 'x';
646  }
647} {1 ghijkl 2 ghijkl}
648do_test like-8.2 {
649  proc newlike {args} {return 1} ;# Alternative LIKE is always return TRUE
650  db function like newlike       ;# Uses -1 for nArg in sqlite3_create_function
651  db cache flush
652  db eval {
653    SELECT 1, x FROM t8 WHERE x LIKE '%h%';
654    SELECT 2, x FROM t8 WHERE x LIKE '%h%' ESCAPE 'x';
655  }
656} {1 ghijkl 2 ghijkl}
657do_test like-8.3 {
658  db function like -argcount 2 newlike
659  db eval {
660    SELECT 1, x FROM t8 WHERE x LIKE '%h%';
661    SELECT 2, x FROM t8 WHERE x LIKE '%h%' ESCAPE 'x';
662  }
663} {1 abcdef 1 ghijkl 1 mnopqr 2 ghijkl}
664do_test like-8.4 {
665  db function like -argcount 3 newlike
666  db eval {
667    SELECT 1, x FROM t8 WHERE x LIKE '%h%';
668    SELECT 2, x FROM t8 WHERE x LIKE '%h%' ESCAPE 'x';
669  }
670} {1 abcdef 1 ghijkl 1 mnopqr 2 abcdef 2 ghijkl 2 mnopqr}
671
672
673ifcapable like_opt&&!icu {
674  # Evaluate SQL.  Return the result set followed by the
675  # and the number of full-scan steps.
676  #
677  db close
678  sqlite3 db test.db
679  proc count_steps {sql} {
680    set r [db eval $sql]
681    lappend r scan [db status step] sort [db status sort]
682  }
683  do_test like-9.1 {
684    count_steps {
685       SELECT x FROM t2 WHERE x LIKE 'x%'
686    }
687  } {xyz scan 0 sort 0}
688  do_test like-9.2 {
689    count_steps {
690       SELECT x FROM t2 WHERE x LIKE '_y%'
691    }
692  } {xyz scan 19 sort 0}
693  do_test like-9.3.1 {
694    set res [sqlite3_exec_hex db {
695       SELECT x FROM t2 WHERE x LIKE '%78%25'
696    }]
697  } {0 {x xyz}}
698  ifcapable explain {
699    do_test like-9.3.2 {
700      set res [sqlite3_exec_hex db {
701         EXPLAIN QUERY PLAN SELECT x FROM t2 WHERE x LIKE '%78%25'
702      }]
703      regexp {INDEX i2} $res
704    } {1}
705  }
706  do_test like-9.4.1 {
707    sqlite3_exec_hex db {INSERT INTO t2 VALUES('%ffhello')}
708    set res [sqlite3_exec_hex db {
709       SELECT substr(x,2) AS x FROM t2 WHERE +x LIKE '%ff%25'
710    }]
711  } {0 {x hello}}
712  do_test like-9.4.2 {
713    set res [sqlite3_exec_hex db {
714       SELECT substr(x,2) AS x FROM t2 WHERE x LIKE '%ff%25'
715    }]
716  } {0 {x hello}}
717  ifcapable explain {
718    do_test like-9.4.3 {
719      set res [sqlite3_exec_hex db {
720         EXPLAIN QUERY PLAN SELECT x FROM t2 WHERE x LIKE '%ff%25'
721      }]
722      regexp {SCAN TABLE t2} $res
723    } {1}
724  }
725  do_test like-9.5.1 {
726    set res [sqlite3_exec_hex db {
727       SELECT x FROM t2 WHERE x LIKE '%fe%25'
728    }]
729  } {0 {}}
730  ifcapable explain {
731    do_test like-9.5.2 {
732      set res [sqlite3_exec_hex db {
733         EXPLAIN QUERY PLAN SELECT x FROM t2 WHERE x LIKE '%fe%25'
734      }]
735      regexp {INDEX i2} $res
736    } {1}
737  }
738
739  # Do an SQL statement.  Append the search count to the end of the result.
740  #
741  proc count sql {
742    set ::sqlite_search_count 0
743    set ::sqlite_like_count 0
744    return [concat [execsql $sql] scan $::sqlite_search_count \
745             like $::sqlite_like_count]
746  }
747
748  # The LIKE and GLOB optimizations do not work on columns with
749  # affinity other than TEXT.
750  # Ticket #3901
751  #
752  do_test like-10.1 {
753    db close
754    sqlite3 db test.db
755    execsql {
756      CREATE TABLE t10(
757        a INTEGER PRIMARY KEY,
758        b INTEGER COLLATE nocase UNIQUE,
759        c NUMBER COLLATE nocase UNIQUE,
760        d BLOB COLLATE nocase UNIQUE,
761        e COLLATE nocase UNIQUE,
762        f TEXT COLLATE nocase UNIQUE
763      );
764      INSERT INTO t10 VALUES(1,1,1,1,1,1);
765      INSERT INTO t10 VALUES(12,12,12,12,12,12);
766      INSERT INTO t10 VALUES(123,123,123,123,123,123);
767      INSERT INTO t10 VALUES(234,234,234,234,234,234);
768      INSERT INTO t10 VALUES(345,345,345,345,345,345);
769      INSERT INTO t10 VALUES(45,45,45,45,45,45);
770    }
771    count {
772      SELECT a FROM t10 WHERE b LIKE '12%' ORDER BY +a;
773    }
774  } {12 123 scan 5 like 6}
775  do_test like-10.2 {
776    count {
777      SELECT a FROM t10 WHERE c LIKE '12%' ORDER BY +a;
778    }
779  } {12 123 scan 5 like 6}
780  do_test like-10.3 {
781    count {
782      SELECT a FROM t10 WHERE d LIKE '12%' ORDER BY +a;
783    }
784  } {12 123 scan 5 like 6}
785  do_test like-10.4 {
786    count {
787      SELECT a FROM t10 WHERE e LIKE '12%' ORDER BY +a;
788    }
789  } {12 123 scan 5 like 6}
790  ifcapable like_match_blobs {
791    do_test like-10.5a {
792      count {
793        SELECT a FROM t10 WHERE f LIKE '12%' ORDER BY +a;
794      }
795    } {12 123 scan 4 like 0}
796  } else {
797    do_test like-10.5b {
798      count {
799        SELECT a FROM t10 WHERE f LIKE '12%' ORDER BY +a;
800      }
801    } {12 123 scan 3 like 0}
802  }
803  do_test like-10.6 {
804    count {
805      SELECT a FROM t10 WHERE a LIKE '12%' ORDER BY +a;
806    }
807  } {12 123 scan 5 like 6}
808  do_test like-10.10 {
809    execsql {
810      CREATE TABLE t10b(
811        a INTEGER PRIMARY KEY,
812        b INTEGER UNIQUE,
813        c NUMBER UNIQUE,
814        d BLOB UNIQUE,
815        e UNIQUE,
816        f TEXT UNIQUE
817      );
818      INSERT INTO t10b SELECT * FROM t10;
819    }
820    count {
821      SELECT a FROM t10b WHERE b GLOB '12*' ORDER BY +a;
822    }
823  } {12 123 scan 5 like 6}
824  do_test like-10.11 {
825    count {
826      SELECT a FROM t10b WHERE c GLOB '12*' ORDER BY +a;
827    }
828  } {12 123 scan 5 like 6}
829  do_test like-10.12 {
830    count {
831      SELECT a FROM t10b WHERE d GLOB '12*' ORDER BY +a;
832    }
833  } {12 123 scan 5 like 6}
834  do_test like-10.13 {
835    count {
836      SELECT a FROM t10b WHERE e GLOB '12*' ORDER BY +a;
837    }
838  } {12 123 scan 5 like 6}
839  ifcapable like_match_blobs {
840    do_test like-10.14 {
841      count {
842        SELECT a FROM t10b WHERE f GLOB '12*' ORDER BY +a;
843      }
844    } {12 123 scan 4 like 0}
845  } else {
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 3 like 0}
851  }
852  do_test like-10.15 {
853    count {
854      SELECT a FROM t10b WHERE a GLOB '12*' ORDER BY +a;
855    }
856  } {12 123 scan 5 like 6}
857}
858
859# LIKE and GLOB where the default collating sequence is not appropriate
860# but an index with the appropriate collating sequence exists.
861#
862do_test like-11.0 {
863  execsql {
864    CREATE TABLE t11(
865      a INTEGER PRIMARY KEY,
866      b TEXT COLLATE nocase,
867      c TEXT COLLATE binary
868    );
869    INSERT INTO t11 VALUES(1, 'a','a');
870    INSERT INTO t11 VALUES(2, 'ab','ab');
871    INSERT INTO t11 VALUES(3, 'abc','abc');
872    INSERT INTO t11 VALUES(4, 'abcd','abcd');
873    INSERT INTO t11 VALUES(5, 'A','A');
874    INSERT INTO t11 VALUES(6, 'AB','AB');
875    INSERT INTO t11 VALUES(7, 'ABC','ABC');
876    INSERT INTO t11 VALUES(8, 'ABCD','ABCD');
877    INSERT INTO t11 VALUES(9, 'x','x');
878    INSERT INTO t11 VALUES(10, 'yz','yz');
879    INSERT INTO t11 VALUES(11, 'X','X');
880    INSERT INTO t11 VALUES(12, 'YZ','YZ');
881    SELECT count(*) FROM t11;
882  }
883} {12}
884do_test like-11.1 {
885  db eval {PRAGMA case_sensitive_like=OFF;}
886  queryplan {
887    SELECT b FROM t11 WHERE b LIKE 'abc%' ORDER BY a;
888  }
889} {abc abcd ABC ABCD nosort t11 *}
890do_test like-11.2 {
891  db eval {PRAGMA case_sensitive_like=ON;}
892  queryplan {
893    SELECT b FROM t11 WHERE b LIKE 'abc%' ORDER BY a;
894  }
895} {abc abcd nosort t11 *}
896do_test like-11.3 {
897  db eval {
898    PRAGMA case_sensitive_like=OFF;
899    CREATE INDEX t11b ON t11(b);
900  }
901  queryplan {
902    SELECT b FROM t11 WHERE b LIKE 'abc%' ORDER BY +a;
903  }
904} {abc abcd ABC ABCD sort {} t11b}
905do_test like-11.4 {
906  db eval {PRAGMA case_sensitive_like=ON;}
907  queryplan {
908    SELECT b FROM t11 WHERE b LIKE 'abc%' ORDER BY a;
909  }
910} {abc abcd nosort t11 *}
911do_test like-11.5 {
912  db eval {
913    PRAGMA case_sensitive_like=OFF;
914    DROP INDEX t11b;
915    CREATE INDEX t11bnc ON t11(b COLLATE nocase);
916  }
917  queryplan {
918    SELECT b FROM t11 WHERE b LIKE 'abc%' ORDER BY +a;
919  }
920} {abc abcd ABC ABCD sort {} t11bnc}
921do_test like-11.6 {
922  db eval {CREATE INDEX t11bb ON t11(b COLLATE binary);}
923  queryplan {
924    SELECT b FROM t11 WHERE b LIKE 'abc%' ORDER BY +a;
925  }
926} {abc abcd ABC ABCD sort {} t11bnc}
927do_test like-11.7 {
928  db eval {PRAGMA case_sensitive_like=ON;}
929  queryplan {
930    SELECT b FROM t11 WHERE b LIKE 'abc%' ORDER BY +a;
931  }
932} {abc abcd sort {} t11bb}
933do_test like-11.8 {
934  db eval {PRAGMA case_sensitive_like=OFF;}
935  queryplan {
936    SELECT b FROM t11 WHERE b GLOB 'abc*' ORDER BY +a;
937  }
938} {abc abcd sort {} t11bb}
939do_test like-11.9 {
940  db eval {
941    CREATE INDEX t11cnc ON t11(c COLLATE nocase);
942    CREATE INDEX t11cb ON t11(c COLLATE binary);
943  }
944  queryplan {
945    SELECT c FROM t11 WHERE c LIKE 'abc%' ORDER BY +a;
946  }
947} {abc abcd ABC ABCD sort {} t11cnc}
948do_test like-11.10 {
949  queryplan {
950    SELECT c FROM t11 WHERE c GLOB 'abc*' ORDER BY +a;
951  }
952} {abc abcd sort {} t11cb}
953
954# A COLLATE clause on the pattern does not change the result of a
955# LIKE operator.
956#
957do_execsql_test like-12.1 {
958  CREATE TABLE t12nc(id INTEGER, x TEXT UNIQUE COLLATE nocase);
959  INSERT INTO t12nc VALUES(1,'abcde'),(2,'uvwxy'),(3,'ABCDEF');
960  CREATE TABLE t12b(id INTEGER, x TEXT UNIQUE COLLATE binary);
961  INSERT INTO t12b VALUES(1,'abcde'),(2,'uvwxy'),(3,'ABCDEF');
962  SELECT id FROM t12nc WHERE x LIKE 'abc%' ORDER BY +id;
963} {1 3}
964do_execsql_test like-12.2 {
965  SELECT id FROM t12b WHERE x LIKE 'abc%' ORDER BY +id;
966} {1 3}
967do_execsql_test like-12.3 {
968  SELECT id FROM t12nc WHERE x LIKE 'abc%' COLLATE binary ORDER BY +id;
969} {1 3}
970do_execsql_test like-12.4 {
971  SELECT id FROM t12b WHERE x LIKE 'abc%' COLLATE binary ORDER BY +id;
972} {1 3}
973do_execsql_test like-12.5 {
974  SELECT id FROM t12nc WHERE x LIKE 'abc%' COLLATE nocase ORDER BY +id;
975} {1 3}
976do_execsql_test like-12.6 {
977  SELECT id FROM t12b WHERE x LIKE 'abc%' COLLATE nocase ORDER BY +id;
978} {1 3}
979
980# Adding a COLLATE clause to the pattern of a LIKE operator does nothing
981# to change the suitability of using an index to satisfy that LIKE
982# operator.
983#
984do_execsql_test like-12.11 {
985  EXPLAIN QUERY PLAN
986  SELECT id FROM t12nc WHERE x LIKE 'abc%' ORDER BY +id;
987} {/SEARCH/}
988do_execsql_test like-12.12 {
989  EXPLAIN QUERY PLAN
990  SELECT id FROM t12b WHERE x LIKE 'abc%' ORDER BY +id;
991} {/SCAN/}
992do_execsql_test like-12.13 {
993  EXPLAIN QUERY PLAN
994  SELECT id FROM t12nc WHERE x LIKE 'abc%' COLLATE nocase ORDER BY +id;
995} {/SEARCH/}
996do_execsql_test like-12.14 {
997  EXPLAIN QUERY PLAN
998  SELECT id FROM t12b WHERE x LIKE 'abc%' COLLATE nocase ORDER BY +id;
999} {/SCAN/}
1000do_execsql_test like-12.15 {
1001  EXPLAIN QUERY PLAN
1002  SELECT id FROM t12nc WHERE x LIKE 'abc%' COLLATE binary ORDER BY +id;
1003} {/SEARCH/}
1004do_execsql_test like-12.16 {
1005  EXPLAIN QUERY PLAN
1006  SELECT id FROM t12b WHERE x LIKE 'abc%' COLLATE binary ORDER BY +id;
1007} {/SCAN/}
1008
1009# Ticket [https://www.sqlite.org/src/tktview/80369eddd5c94d49f7fbbcf5]
1010# 2016-01-20
1011#
1012do_execsql_test like-13.1 {
1013  SELECT char(0x304d) LIKE char(0x306d);
1014} {0}
1015do_execsql_test like-13.2 {
1016  SELECT char(0x4d) LIKE char(0x306d);
1017} {0}
1018do_execsql_test like-13.3 {
1019  SELECT char(0x304d) LIKE char(0x6d);
1020} {0}
1021do_execsql_test like-13.4 {
1022  SELECT char(0x4d) LIKE char(0x6d);
1023} {1}
1024
1025# Performance testing for patterns with many wildcards.  These LIKE and GLOB
1026# patterns were quite slow with SQLite 3.15.2 and earlier.
1027#
1028do_test like-14.1 {
1029  set x [lindex [time {
1030    db one {SELECT 'aaaaaaaaaaaaaaaaaaaaaaaaaaaaaaaz'GLOB'*a*a*a*a*a*a*a*a*y'}
1031  }] 0]
1032  puts -nonewline " ($x ms - want less than 1000) "
1033  expr {$x<1000}
1034} {1}
1035ifcapable !icu {
1036  do_test like-14.2 {
1037    set x [lindex [time {
1038      db one {SELECT 'aaaaaaaaaaaaaaaaaaaaaaaaaaaaaaaz'LIKE'%a%a%a%a%a%a%a%a%y'}
1039    }] 0]
1040    puts -nonewline " ($x ms - want less than 1000) "
1041    expr {$x<1000}
1042  } {1}
1043}
1044
1045finish_test
1046