3 # The author disclaims copyright to this source code. In place of
4 # a legal notice, here is a blessing:
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.
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
16 # $Id: like.test,v 1.13 2009/06/07 23:45:11 drh Exp $
18 set testdir [file dirname $argv0]
19 source $testdir/tester.tcl
22 # Create some sample data to work with.
26 CREATE TABLE t1(x TEXT);
44 db eval {INSERT INTO t1 VALUES(:str)}
47 SELECT count(*) FROM t1;
51 # Test that both case sensitive and insensitive version of LIKE work.
55 SELECT x FROM t1 WHERE x LIKE 'abc' ORDER BY 1;
60 SELECT x FROM t1 WHERE x GLOB 'abc' ORDER BY 1;
65 SELECT x FROM t1 WHERE x LIKE 'ABC' ORDER BY 1;
70 SELECT x FROM t1 WHERE x LIKE 'aBc' ORDER BY 1;
74 # Use sqlite3_exec() to verify fix for ticket [25ee81271091] 2011-06-26
75 sqlite3_exec db {PRAGMA case_sensitive_like=on}
79 SELECT x FROM t1 WHERE x LIKE 'abc' ORDER BY 1;
84 PRAGMA case_sensitive_like; -- no argument; does not change setting
85 SELECT x FROM t1 WHERE x LIKE 'abc' ORDER BY 1;
90 SELECT x FROM t1 WHERE x GLOB 'abc' ORDER BY 1;
95 SELECT x FROM t1 WHERE x LIKE 'ABC' ORDER BY 1;
100 SELECT x FROM t1 WHERE x LIKE 'aBc' ORDER BY 1;
105 PRAGMA case_sensitive_like=off;
106 SELECT x FROM t1 WHERE x LIKE 'abc' ORDER BY 1;
111 PRAGMA case_sensitive_like; -- No argument, does not change setting.
112 SELECT x FROM t1 WHERE x LIKE 'abc' ORDER BY 1;
116 # Tests of the REGEXP operator
119 proc test_regexp {a b} {
120 return [regexp $a $b]
122 db function regexp -argcount 2 test_regexp
124 SELECT x FROM t1 WHERE x REGEXP 'abc' ORDER BY 1;
126 } {{ABC abc xyz} abc abcd}
129 SELECT x FROM t1 WHERE x REGEXP '^abc' ORDER BY 1;
133 # Tests of the MATCH operator
136 proc test_match {a b} {
137 return [string match $a $b]
139 db function match -argcount 2 test_match
141 SELECT x FROM t1 WHERE x MATCH '*abc*' ORDER BY 1;
143 } {{ABC abc xyz} abc abcd}
146 SELECT x FROM t1 WHERE x MATCH 'abc*' ORDER BY 1;
150 # For the remaining tests, we need to have the like optimizations
153 ifcapable !like_opt {
158 # This procedure executes the SQL. Then it appends to the result the
159 # "sort" or "nosort" keyword (as in the cksort procedure above) then
160 # it appends the names of the table and index used.
162 proc queryplan {sql} {
163 set ::sqlite_sort_count 0
165 set data [execsql $sql]
166 if {$::sqlite_sort_count} {set x sort} {set x nosort}
168 set eqp [execsql "EXPLAIN QUERY PLAN $sql"]
170 foreach {a b c x} $eqp {
171 if {[regexp { TABLE (\w+ AS )?(\w+) USING COVERING INDEX (\w+)\y} \
172 $x all as tab idx]} {
174 } elseif {[regexp { TABLE (\w+ AS )?(\w+) USING.* INDEX (\w+)\y} \
175 $x all as tab idx]} {
176 lappend data $tab $idx
177 } elseif {[regexp { TABLE (\w+ AS )?(\w+)\y} $x all as tab]} {
184 # Perform tests on the like optimization.
186 # With no index on t1.x and with case sensitivity turned off, no optimization
190 set sqlite_like_count 0
192 SELECT x FROM t1 WHERE x LIKE 'abc%' ORDER BY 1;
194 } {ABC {ABC abc xyz} abc abcd sort t1 *}
196 set sqlite_like_count
199 # With an index on t1.x and case sensitivity on, optimize completely.
201 do_test like-3.3.100 {
202 set sqlite_like_count 0
204 PRAGMA case_sensitive_like=on;
205 CREATE INDEX i1 ON t1(x);
208 SELECT x FROM t1 WHERE x LIKE 'abc%' ORDER BY 1;
210 } {abc abcd nosort {} i1}
211 do_test like-3.3.100.cnt {
212 set sqlite_like_count
215 # The like optimization works even when the pattern is a bound parameter
217 # Exception: It does not work if sqlite3_prepare() is used instead of
218 # sqlite3_prepare_v2(), as in that case the statement cannot be reprepared
219 # after the parameter is bound.
221 unset -nocomplain ::likepat
223 if {[permutation]!="prepare"} {
224 do_test like-3.3.102 {
225 set sqlite_like_count 0
227 SELECT x FROM t1 WHERE x LIKE $::likepat ORDER BY 1;
229 } {abc abcd nosort {} i1}
230 do_test like-3.3.103 {
231 set sqlite_like_count
235 # Except, the like optimization does not work for bound parameters if
236 # the query planner stability guarantee is active.
238 do_test like-3.3.104 {
239 set sqlite_like_count 0
240 sqlite3_db_config db QPSG 1
242 SELECT x FROM t1 WHERE x LIKE $::likepat ORDER BY 1;
244 } {abc abcd nosort {} i1}
245 do_test like-3.3.105 {
246 set sqlite_like_count
249 # The query planner stability guarantee does not disrupt explicit patterns
251 do_test like-3.3.105 {
252 set sqlite_like_count 0
254 SELECT x FROM t1 WHERE x LIKE 'abc%' ORDER BY 1;
256 } {abc abcd nosort {} i1}
257 do_test like-3.3.106 {
258 set sqlite_like_count
260 sqlite3_db_config db QPSG 0
262 # The LIKE optimization still works when the RHS is a string with no
263 # wildcard. Ticket [e090183531fc2747]
267 SELECT x FROM t1 WHERE x LIKE 'a' ORDER BY 1;
272 SELECT x FROM t1 WHERE x LIKE 'ab' ORDER BY 1;
277 SELECT x FROM t1 WHERE x LIKE 'abcd' ORDER BY 1;
279 } {abcd nosort {} i1}
282 SELECT x FROM t1 WHERE x LIKE 'abcde' ORDER BY 1;
287 # Partial optimization when the pattern does not end in '%'
290 set sqlite_like_count 0
292 SELECT x FROM t1 WHERE x LIKE 'a_c' ORDER BY 1;
296 set sqlite_like_count
299 set sqlite_like_count 0
301 SELECT x FROM t1 WHERE x LIKE 'ab%d' ORDER BY 1;
303 } {abcd abd nosort {} i1}
305 set sqlite_like_count
308 set sqlite_like_count 0
310 SELECT x FROM t1 WHERE x LIKE 'a_c%' ORDER BY 1;
312 } {abc abcd nosort {} i1}
314 set sqlite_like_count
317 # No optimization when the pattern begins with a wildcard.
318 # Note that the index is still used but only for sorting.
321 set sqlite_like_count 0
323 SELECT x FROM t1 WHERE x LIKE '%bcd' ORDER BY 1;
325 } {abcd bcd nosort {} i1}
327 set sqlite_like_count
330 # No optimization for case insensitive LIKE
333 set sqlite_like_count 0
334 db eval {PRAGMA case_sensitive_like=off;}
336 SELECT x FROM t1 WHERE x LIKE 'abc%' ORDER BY 1;
338 } {ABC {ABC abc xyz} abc abcd nosort {} i1}
340 set sqlite_like_count
343 # No optimization without an index.
346 set sqlite_like_count 0
348 PRAGMA case_sensitive_like=on;
352 SELECT x FROM t1 WHERE x LIKE 'abc%' ORDER BY 1;
354 } {abc abcd sort t1 *}
356 set sqlite_like_count
359 # No GLOB optimization without an index.
362 set sqlite_like_count 0
364 SELECT x FROM t1 WHERE x GLOB 'abc*' ORDER BY 1;
366 } {abc abcd sort t1 *}
368 set sqlite_like_count
371 # GLOB is optimized regardless of the case_sensitive_like setting.
374 set sqlite_like_count 0
375 db eval {CREATE INDEX i1 ON t1(x);}
377 SELECT x FROM t1 WHERE x GLOB 'abc*' ORDER BY 1;
379 } {abc abcd nosort {} i1}
381 set sqlite_like_count
384 set sqlite_like_count 0
385 db eval {PRAGMA case_sensitive_like=on;}
387 SELECT x FROM t1 WHERE x GLOB 'abc*' ORDER BY 1;
389 } {abc abcd nosort {} i1}
391 set sqlite_like_count
394 set sqlite_like_count 0
395 db eval {PRAGMA case_sensitive_like=off;}
397 SELECT x FROM t1 WHERE x GLOB 'a[bc]d' ORDER BY 1;
399 } {abd acd nosort {} i1}
401 set sqlite_like_count
404 # GLOB optimization when there is no wildcard. Ticket [e090183531fc2747]
408 SELECT x FROM t1 WHERE x GLOB 'a' ORDER BY 1;
413 SELECT x FROM t1 WHERE x GLOB 'abcd' ORDER BY 1;
415 } {abcd nosort {} i1}
418 SELECT x FROM t1 WHERE x GLOB 'abcde' ORDER BY 1;
424 # No optimization if the LHS of the LIKE is not a column name or
425 # if the RHS is not a string.
428 execsql {PRAGMA case_sensitive_like=on}
429 set sqlite_like_count 0
431 SELECT x FROM t1 WHERE x LIKE 'abc%' ORDER BY 1
433 } {abc abcd nosort {} i1}
435 set sqlite_like_count
438 set sqlite_like_count 0
440 SELECT x FROM t1 WHERE +x LIKE 'abc%' ORDER BY 1
442 } {abc abcd nosort {} i1}
444 set sqlite_like_count
447 set sqlite_like_count 0
449 SELECT x FROM t1 WHERE x LIKE ('ab' || 'c%') ORDER BY 1
451 } {abc abcd nosort {} i1}
453 set sqlite_like_count
456 # Collating sequences on the index disable the LIKE optimization.
457 # Or if the NOCASE collating sequence is used, the LIKE optimization
458 # is enabled when case_sensitive_like is OFF.
461 execsql {PRAGMA case_sensitive_like=off}
462 set sqlite_like_count 0
464 SELECT x FROM t1 WHERE x LIKE 'abc%' ORDER BY 1
466 } {ABC {ABC abc xyz} abc abcd nosort {} i1}
468 set sqlite_like_count
472 CREATE TABLE t2(x TEXT COLLATE NOCASE);
473 INSERT INTO t2 SELECT * FROM t1 ORDER BY rowid;
474 CREATE INDEX i2 ON t2(x COLLATE NOCASE);
476 set sqlite_like_count 0
478 SELECT x FROM t2 WHERE x LIKE 'abc%' ORDER BY 1
480 } {abc ABC {ABC abc xyz} abcd nosort {} i2}
482 set sqlite_like_count
486 PRAGMA case_sensitive_like=on;
488 set sqlite_like_count 0
490 SELECT x FROM t2 WHERE x LIKE 'abc%' ORDER BY 1
492 } {abc abcd nosort {} i2}
494 set sqlite_like_count
498 PRAGMA case_sensitive_like=off;
500 set sqlite_like_count 0
502 SELECT x FROM t2 WHERE x GLOB 'abc*' ORDER BY 1
504 } {abc abcd nosort {} i2}
506 set sqlite_like_count
509 execsql {PRAGMA case_sensitive_like=off}
510 set sqlite_like_count 0
512 SELECT x FROM t1 WHERE x LIKE 'ABC%' ORDER BY 1
514 } {ABC {ABC abc xyz} abc abcd nosort {} i1}
516 set sqlite_like_count
519 set sqlite_like_count 0
521 SELECT x FROM t2 WHERE x LIKE 'ABC%' ORDER BY 1
523 } {abc ABC {ABC abc xyz} abcd nosort {} i2}
525 set sqlite_like_count
529 PRAGMA case_sensitive_like=on;
531 set sqlite_like_count 0
533 SELECT x FROM t2 WHERE x LIKE 'ABC%' ORDER BY 1
535 } {ABC {ABC abc xyz} nosort {} i2}
537 set sqlite_like_count
541 PRAGMA case_sensitive_like=off;
543 set sqlite_like_count 0
545 SELECT x FROM t2 WHERE x GLOB 'ABC*' ORDER BY 1
547 } {ABC {ABC abc xyz} nosort {} i2}
549 set sqlite_like_count
552 # Boundary case. The prefix for a LIKE comparison is rounded up
553 # when constructing the comparison. Example: "ab" becomes "ac".
554 # In other words, the last character is increased by one.
556 # Make sure this happens correctly when the last character is a
557 # "z" and we are doing case-insensitive comparisons.
563 PRAGMA case_sensitive_like=off;
564 INSERT INTO t2 VALUES('ZZ-upper-upper');
565 INSERT INTO t2 VALUES('zZ-lower-upper');
566 INSERT INTO t2 VALUES('Zz-upper-lower');
567 INSERT INTO t2 VALUES('zz-lower-lower');
570 SELECT x FROM t2 WHERE x LIKE 'zz%';
572 } {zz-lower-lower zZ-lower-upper Zz-upper-lower ZZ-upper-upper nosort {} i2}
575 SELECT x FROM t2 WHERE x LIKE 'zZ%';
577 } {zz-lower-lower zZ-lower-upper Zz-upper-lower ZZ-upper-upper nosort {} i2}
580 SELECT x FROM t2 WHERE x LIKE 'Zz%';
582 } {zz-lower-lower zZ-lower-upper Zz-upper-lower ZZ-upper-upper nosort {} i2}
585 SELECT x FROM t2 WHERE x LIKE 'ZZ%';
587 } {zz-lower-lower zZ-lower-upper Zz-upper-lower ZZ-upper-upper nosort {} i2}
590 PRAGMA case_sensitive_like=on;
591 CREATE TABLE t3(x TEXT);
592 CREATE INDEX i3 ON t3(x);
593 INSERT INTO t3 VALUES('ZZ-upper-upper');
594 INSERT INTO t3 VALUES('zZ-lower-upper');
595 INSERT INTO t3 VALUES('Zz-upper-lower');
596 INSERT INTO t3 VALUES('zz-lower-lower');
599 SELECT x FROM t3 WHERE x LIKE 'zz%';
601 } {zz-lower-lower nosort {} i3}
604 SELECT x FROM t3 WHERE x LIKE 'zZ%';
606 } {zZ-lower-upper nosort {} i3}
609 SELECT x FROM t3 WHERE x LIKE 'Zz%';
611 } {Zz-upper-lower nosort {} i3}
614 SELECT x FROM t3 WHERE x LIKE 'ZZ%';
616 } {ZZ-upper-upper nosort {} i3}
621 # Make sure the LIKE prefix optimization does not strip off leading
622 # characters of the like pattern that happen to be quote characters.
625 foreach x { 'abc 'bcd 'def 'ax } {
626 set x2 '[string map {' ''} $x]'
627 db eval "INSERT INTO t2 VALUES($x2)"
630 SELECT * FROM t2 WHERE x LIKE '''a%'
636 SELECT rowid, * FROM t1 WHERE rowid GLOB '1*' ORDER BY rowid;
638 } {1 a 10 ABC 11 CDE 12 {ABC abc xyz}}
642 # Overloading the LIKE function with -1 for the number of arguments
643 # will overload both the 2-argument and the 3-argument LIKE.
648 INSERT INTO t8 VALUES('abcdef');
649 INSERT INTO t8 VALUES('ghijkl');
650 INSERT INTO t8 VALUES('mnopqr');
651 SELECT 1, x FROM t8 WHERE x LIKE '%h%';
652 SELECT 2, x FROM t8 WHERE x LIKE '%h%' ESCAPE 'x';
654 } {1 ghijkl 2 ghijkl}
656 proc newlike {args} {return 1} ;# Alternative LIKE is always return TRUE
657 db function like newlike ;# Uses -1 for nArg in sqlite3_create_function
660 SELECT 1, x FROM t8 WHERE x LIKE '%h%';
661 SELECT 2, x FROM t8 WHERE x LIKE '%h%' ESCAPE 'x';
663 } {1 ghijkl 2 ghijkl}
665 db function like -argcount 2 newlike
667 SELECT 1, x FROM t8 WHERE x LIKE '%h%';
668 SELECT 2, x FROM t8 WHERE x LIKE '%h%' ESCAPE 'x';
670 } {1 abcdef 1 ghijkl 1 mnopqr 2 ghijkl}
672 db function like -argcount 3 newlike
674 SELECT 1, x FROM t8 WHERE x LIKE '%h%';
675 SELECT 2, x FROM t8 WHERE x LIKE '%h%' ESCAPE 'x';
677 } {1 abcdef 1 ghijkl 1 mnopqr 2 abcdef 2 ghijkl 2 mnopqr}
680 ifcapable like_opt&&!icu {
681 # Evaluate SQL. Return the result set followed by the
682 # and the number of full-scan steps.
686 proc count_steps {sql} {
688 lappend r scan [db status step] sort [db status sort]
692 SELECT x FROM t2 WHERE x LIKE 'x%'
694 } {xyz scan 0 sort 0}
697 SELECT x FROM t2 WHERE x LIKE '_y%'
699 } {xyz scan 19 sort 0}
701 set res [sqlite3_exec_hex db {
702 SELECT x FROM t2 WHERE x LIKE '%78%25'
707 set res [sqlite3_exec_hex db {
708 EXPLAIN QUERY PLAN SELECT x FROM t2 WHERE x LIKE '%78%25'
710 regexp {INDEX i2} $res
714 sqlite3_exec_hex db {INSERT INTO t2 VALUES('%ffhello')}
715 set res [sqlite3_exec_hex db {
716 SELECT substr(x,2) AS x FROM t2 WHERE +x LIKE '%ff%25'
720 set res [sqlite3_exec_hex db {
721 SELECT substr(x,2) AS x FROM t2 WHERE x LIKE '%ff%25'
726 set res [sqlite3_exec_hex db {
727 EXPLAIN QUERY PLAN SELECT x FROM t2 WHERE x LIKE '%ff%25'
729 regexp {SCAN TABLE t2} $res
733 set res [sqlite3_exec_hex db {
734 SELECT x FROM t2 WHERE x LIKE '%fe%25'
739 set res [sqlite3_exec_hex db {
740 EXPLAIN QUERY PLAN SELECT x FROM t2 WHERE x LIKE '%fe%25'
742 regexp {INDEX i2} $res
746 # Do an SQL statement. Append the search count to the end of the result.
749 set ::sqlite_search_count 0
750 set ::sqlite_like_count 0
751 return [concat [execsql $sql] scan $::sqlite_search_count \
752 like $::sqlite_like_count]
755 # The LIKE and GLOB optimizations do not work on columns with
756 # affinity other than TEXT.
764 a INTEGER PRIMARY KEY,
765 b INTEGER COLLATE nocase UNIQUE,
766 c NUMBER COLLATE nocase UNIQUE,
767 d BLOB COLLATE nocase UNIQUE,
768 e COLLATE nocase UNIQUE,
769 f TEXT COLLATE nocase UNIQUE
771 INSERT INTO t10 VALUES(1,1,1,1,1,1);
772 INSERT INTO t10 VALUES(12,12,12,12,12,12);
773 INSERT INTO t10 VALUES(123,123,123,123,123,123);
774 INSERT INTO t10 VALUES(234,234,234,234,234,234);
775 INSERT INTO t10 VALUES(345,345,345,345,345,345);
776 INSERT INTO t10 VALUES(45,45,45,45,45,45);
779 SELECT a FROM t10 WHERE b LIKE '12%' ORDER BY +a;
781 } {12 123 scan 5 like 6}
784 SELECT a FROM t10 WHERE c LIKE '12%' ORDER BY +a;
786 } {12 123 scan 5 like 6}
789 SELECT a FROM t10 WHERE d LIKE '12%' ORDER BY +a;
791 } {12 123 scan 5 like 6}
794 SELECT a FROM t10 WHERE e LIKE '12%' ORDER BY +a;
796 } {12 123 scan 5 like 6}
797 ifcapable like_match_blobs {
800 SELECT a FROM t10 WHERE f LIKE '12%' ORDER BY +a;
802 } {12 123 scan 4 like 0}
806 SELECT a FROM t10 WHERE f LIKE '12%' ORDER BY +a;
808 } {12 123 scan 3 like 0}
812 SELECT a FROM t10 WHERE a LIKE '12%' ORDER BY +a;
814 } {12 123 scan 5 like 6}
818 a INTEGER PRIMARY KEY,
825 INSERT INTO t10b SELECT * FROM t10;
828 SELECT a FROM t10b WHERE b GLOB '12*' ORDER BY +a;
830 } {12 123 scan 5 like 6}
833 SELECT a FROM t10b WHERE c GLOB '12*' ORDER BY +a;
835 } {12 123 scan 5 like 6}
838 SELECT a FROM t10b WHERE d GLOB '12*' ORDER BY +a;
840 } {12 123 scan 5 like 6}
843 SELECT a FROM t10b WHERE e GLOB '12*' ORDER BY +a;
845 } {12 123 scan 5 like 6}
846 ifcapable like_match_blobs {
849 SELECT a FROM t10b WHERE f GLOB '12*' ORDER BY +a;
851 } {12 123 scan 4 like 0}
855 SELECT a FROM t10b WHERE f GLOB '12*' ORDER BY +a;
857 } {12 123 scan 3 like 0}
861 SELECT a FROM t10b WHERE a GLOB '12*' ORDER BY +a;
863 } {12 123 scan 5 like 6}
866 # LIKE and GLOB where the default collating sequence is not appropriate
867 # but an index with the appropriate collating sequence exists.
872 a INTEGER PRIMARY KEY,
873 b TEXT COLLATE nocase,
874 c TEXT COLLATE binary
876 INSERT INTO t11 VALUES(1, 'a','a');
877 INSERT INTO t11 VALUES(2, 'ab','ab');
878 INSERT INTO t11 VALUES(3, 'abc','abc');
879 INSERT INTO t11 VALUES(4, 'abcd','abcd');
880 INSERT INTO t11 VALUES(5, 'A','A');
881 INSERT INTO t11 VALUES(6, 'AB','AB');
882 INSERT INTO t11 VALUES(7, 'ABC','ABC');
883 INSERT INTO t11 VALUES(8, 'ABCD','ABCD');
884 INSERT INTO t11 VALUES(9, 'x','x');
885 INSERT INTO t11 VALUES(10, 'yz','yz');
886 INSERT INTO t11 VALUES(11, 'X','X');
887 INSERT INTO t11 VALUES(12, 'YZ','YZ');
888 SELECT count(*) FROM t11;
892 db eval {PRAGMA case_sensitive_like=OFF;}
894 SELECT b FROM t11 WHERE b LIKE 'abc%' ORDER BY a;
896 } {abc abcd ABC ABCD nosort t11 *}
898 db eval {PRAGMA case_sensitive_like=ON;}
900 SELECT b FROM t11 WHERE b LIKE 'abc%' ORDER BY a;
902 } {abc abcd nosort t11 *}
905 PRAGMA case_sensitive_like=OFF;
906 CREATE INDEX t11b ON t11(b);
909 SELECT b FROM t11 WHERE b LIKE 'abc%' ORDER BY +a;
911 } {abc abcd ABC ABCD sort {} t11b}
913 db eval {PRAGMA case_sensitive_like=ON;}
915 SELECT b FROM t11 WHERE b LIKE 'abc%' ORDER BY a;
917 } {abc abcd nosort t11 *}
920 PRAGMA case_sensitive_like=OFF;
922 CREATE INDEX t11bnc ON t11(b COLLATE nocase);
925 SELECT b FROM t11 WHERE b LIKE 'abc%' ORDER BY +a;
927 } {abc abcd ABC ABCD sort {} t11bnc}
929 db eval {CREATE INDEX t11bb ON t11(b COLLATE binary);}
931 SELECT b FROM t11 WHERE b LIKE 'abc%' ORDER BY +a;
933 } {abc abcd ABC ABCD sort {} t11bnc}
935 db eval {PRAGMA case_sensitive_like=ON;}
937 SELECT b FROM t11 WHERE b LIKE 'abc%' ORDER BY +a;
939 } {abc abcd sort {} t11bb}
941 db eval {PRAGMA case_sensitive_like=OFF;}
943 SELECT b FROM t11 WHERE b GLOB 'abc*' ORDER BY +a;
945 } {abc abcd sort {} t11bb}
948 CREATE INDEX t11cnc ON t11(c COLLATE nocase);
949 CREATE INDEX t11cb ON t11(c COLLATE binary);
952 SELECT c FROM t11 WHERE c LIKE 'abc%' ORDER BY +a;
954 } {abc abcd ABC ABCD sort {} t11cnc}
957 SELECT c FROM t11 WHERE c GLOB 'abc*' ORDER BY +a;
959 } {abc abcd sort {} t11cb}
961 # A COLLATE clause on the pattern does not change the result of a
964 do_execsql_test like-12.1 {
965 CREATE TABLE t12nc(id INTEGER, x TEXT UNIQUE COLLATE nocase);
966 INSERT INTO t12nc VALUES(1,'abcde'),(2,'uvwxy'),(3,'ABCDEF');
967 CREATE TABLE t12b(id INTEGER, x TEXT UNIQUE COLLATE binary);
968 INSERT INTO t12b VALUES(1,'abcde'),(2,'uvwxy'),(3,'ABCDEF');
969 SELECT id FROM t12nc WHERE x LIKE 'abc%' ORDER BY +id;
971 do_execsql_test like-12.2 {
972 SELECT id FROM t12b WHERE x LIKE 'abc%' ORDER BY +id;
974 do_execsql_test like-12.3 {
975 SELECT id FROM t12nc WHERE x LIKE 'abc%' COLLATE binary ORDER BY +id;
977 do_execsql_test like-12.4 {
978 SELECT id FROM t12b WHERE x LIKE 'abc%' COLLATE binary ORDER BY +id;
980 do_execsql_test like-12.5 {
981 SELECT id FROM t12nc WHERE x LIKE 'abc%' COLLATE nocase ORDER BY +id;
983 do_execsql_test like-12.6 {
984 SELECT id FROM t12b WHERE x LIKE 'abc%' COLLATE nocase ORDER BY +id;
987 # Adding a COLLATE clause to the pattern of a LIKE operator does nothing
988 # to change the suitability of using an index to satisfy that LIKE
991 do_execsql_test like-12.11 {
993 SELECT id FROM t12nc WHERE x LIKE 'abc%' ORDER BY +id;
995 do_execsql_test like-12.12 {
997 SELECT id FROM t12b WHERE x LIKE 'abc%' ORDER BY +id;
999 do_execsql_test like-12.13 {
1001 SELECT id FROM t12nc WHERE x LIKE 'abc%' COLLATE nocase ORDER BY +id;
1003 do_execsql_test like-12.14 {
1005 SELECT id FROM t12b WHERE x LIKE 'abc%' COLLATE nocase ORDER BY +id;
1007 do_execsql_test like-12.15 {
1009 SELECT id FROM t12nc WHERE x LIKE 'abc%' COLLATE binary ORDER BY +id;
1011 do_execsql_test like-12.16 {
1013 SELECT id FROM t12b WHERE x LIKE 'abc%' COLLATE binary ORDER BY +id;
1016 # Ticket [https://www.sqlite.org/src/tktview/80369eddd5c94d49f7fbbcf5]
1019 do_execsql_test like-13.1 {
1020 SELECT char(0x304d) LIKE char(0x306d);
1022 do_execsql_test like-13.2 {
1023 SELECT char(0x4d) LIKE char(0x306d);
1025 do_execsql_test like-13.3 {
1026 SELECT char(0x304d) LIKE char(0x6d);
1028 do_execsql_test like-13.4 {
1029 SELECT char(0x4d) LIKE char(0x6d);
1032 # Performance testing for patterns with many wildcards. These LIKE and GLOB
1033 # patterns were quite slow with SQLite 3.15.2 and earlier.
1036 set x [lindex [time {
1037 db one {SELECT 'aaaaaaaaaaaaaaaaaaaaaaaaaaaaaaaz'GLOB'*a*a*a*a*a*a*a*a*y'}
1039 puts -nonewline " ($x ms - want less than 1000) "
1044 set x [lindex [time {
1045 db one {SELECT 'aaaaaaaaaaaaaaaaaaaaaaaaaaaaaaaz'LIKE'%a%a%a%a%a%a%a%a%y'}
1047 puts -nonewline " ($x ms - want less than 1000) "
1053 # As of 2017-07-27 (3.21.0) the LIKE optimization works with ESCAPE as
1054 # long as the ESCAPE is a single-byte literal.
1058 do_execsql_test like-15.100 {
1059 CREATE TABLE t15(x TEXT COLLATE nocase, y, PRIMARY KEY(x));
1060 INSERT INTO t15(x,y) VALUES
1061 ('abcde',1), ('ab%de',2), ('a_cde',3),
1062 ('uvwxy',11),('uvwx%',12),('uvwx_',13),
1063 ('_bcde',21),('%bcde',22),
1064 ('abcd_',31),('abcd%',32),
1066 SELECT y FROM t15 WHERE x LIKE 'ab/%d%' ESCAPE '/';
1068 do_execsql_test like-15.101 {
1070 SELECT y FROM t15 WHERE x LIKE 'ab/%d%' ESCAPE '/';
1072 do_execsql_test like-15.102 {
1074 SELECT y FROM t15 WHERE x LIKE 'ab/%d%' ESCAPE '//';
1076 do_execsql_test like-15.103 {
1078 SELECT y FROM t15 WHERE x LIKE 'ab/%d%' ESCAPE '';
1080 do_execsql_test like-15.110 {
1081 SELECT y FROM t15 WHERE x LIKE 'abcdx%%' ESCAPE 'x';
1083 do_execsql_test like-15.111 {
1084 SELECT y FROM t15 WHERE x LIKE 'abx%%' ESCAPE 'x' ORDER BY +y
1086 do_execsql_test like-15.112 {
1088 SELECT y FROM t15 WHERE x LIKE 'abx%%' ESCAPE 'x' ORDER BY +y
1090 do_execsql_test like-15.120 {
1091 SELECT y FROM t15 WHERE x LIKE '/%bc%' ESCAPE '/';
1093 do_execsql_test like-15.121 {
1095 SELECT y FROM t15 WHERE x LIKE '/%bc%' ESCAPE '/';
1099 #-------------------------------------------------------------------------
1100 # Tests for ticket [b1d8c79314].
1103 do_execsql_test 16.0 {
1104 CREATE TABLE t1(a INTEGER COLLATE NOCASE);
1105 CREATE INDEX i1 ON t1(a);
1106 INSERT INTO t1 VALUES(' 1x');
1107 INSERT INTO t1 VALUES(' 1-');
1109 do_execsql_test 16.1 {
1110 SELECT * FROM t1 WHERE a LIKE ' 1%';
1112 do_execsql_test 16.2 {
1113 SELECT * FROM t1 WHERE a LIKE ' 1-';
1117 # The ESCAPE clause on LIKE takes precedence over wildcards
1119 do_execsql_test 17.0 {
1120 DROP TABLE IF EXISTS t1;
1121 CREATE TABLE t1(id INTEGER PRIMARY KEY, x TEXT);
1122 INSERT INTO t1 VALUES
1128 SELECT id FROM t1 WHERE x LIKE 'abc%%' ESCAPE '%';
1130 do_execsql_test 17.1 {
1131 SELECT id FROM t1 WHERE x LIKE 'abc__' ESCAPE '_';