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
21 # Create some sample data to work with.
25 CREATE TABLE t1(x TEXT);
43 db eval {INSERT INTO t1 VALUES(:str)}
46 SELECT count(*) FROM t1;
50 # Test that both case sensitive and insensitive version of LIKE work.
54 SELECT x FROM t1 WHERE x LIKE 'abc' ORDER BY 1;
59 SELECT x FROM t1 WHERE x GLOB 'abc' ORDER BY 1;
64 SELECT x FROM t1 WHERE x LIKE 'ABC' ORDER BY 1;
69 SELECT x FROM t1 WHERE x LIKE 'aBc' ORDER BY 1;
73 # Use sqlite3_exec() to verify fix for ticket [25ee81271091] 2011-06-26
74 sqlite3_exec db {PRAGMA case_sensitive_like=on}
78 SELECT x FROM t1 WHERE x LIKE 'abc' ORDER BY 1;
83 PRAGMA case_sensitive_like; -- no argument; does not change setting
84 SELECT x FROM t1 WHERE x LIKE 'abc' ORDER BY 1;
89 SELECT x FROM t1 WHERE x GLOB 'abc' ORDER BY 1;
94 SELECT x FROM t1 WHERE x LIKE 'ABC' ORDER BY 1;
99 SELECT x FROM t1 WHERE x LIKE 'aBc' ORDER BY 1;
104 PRAGMA case_sensitive_like=off;
105 SELECT x FROM t1 WHERE x LIKE 'abc' ORDER BY 1;
110 PRAGMA case_sensitive_like; -- No argument, does not change setting.
111 SELECT x FROM t1 WHERE x LIKE 'abc' ORDER BY 1;
115 # Tests of the REGEXP operator
118 proc test_regexp {a b} {
119 return [regexp $a $b]
121 db function regexp -argcount 2 test_regexp
123 SELECT x FROM t1 WHERE x REGEXP 'abc' ORDER BY 1;
125 } {{ABC abc xyz} abc abcd}
128 SELECT x FROM t1 WHERE x REGEXP '^abc' ORDER BY 1;
132 # Tests of the MATCH operator
135 proc test_match {a b} {
136 return [string match $a $b]
138 db function match -argcount 2 test_match
140 SELECT x FROM t1 WHERE x MATCH '*abc*' ORDER BY 1;
142 } {{ABC abc xyz} abc abcd}
145 SELECT x FROM t1 WHERE x MATCH 'abc*' ORDER BY 1;
149 # For the remaining tests, we need to have the like optimizations
152 ifcapable !like_opt {
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.
161 proc queryplan {sql} {
162 set ::sqlite_sort_count 0
164 set data [execsql $sql]
165 if {$::sqlite_sort_count} {set x sort} {set x nosort}
167 set eqp [execsql "EXPLAIN QUERY PLAN $sql"]
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]} {
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]} {
183 # Perform tests on the like optimization.
185 # With no index on t1.x and with case sensitivity turned off, no optimization
189 set sqlite_like_count 0
191 SELECT x FROM t1 WHERE x LIKE 'abc%' ORDER BY 1;
193 } {ABC {ABC abc xyz} abc abcd sort t1 *}
195 set sqlite_like_count
198 # With an index on t1.x and case sensitivity on, optimize completely.
200 do_test like-3.3.100 {
201 set sqlite_like_count 0
203 PRAGMA case_sensitive_like=on;
204 CREATE INDEX i1 ON t1(x);
207 SELECT x FROM t1 WHERE x LIKE 'abc%' ORDER BY 1;
209 } {abc abcd nosort {} i1}
210 do_test like-3.3.100.cnt {
211 set sqlite_like_count
214 # The like optimization works even when the pattern is a bound parameter
216 # 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.
220 unset -nocomplain ::likepat
222 if {[permutation]!="prepare"} {
223 do_test like-3.3.102 {
224 set sqlite_like_count 0
226 SELECT x FROM t1 WHERE x LIKE $::likepat ORDER BY 1;
228 } {abc abcd nosort {} i1}
229 do_test like-3.3.103 {
230 set sqlite_like_count
234 # Except, the like optimization does not work for bound parameters if
235 # the query planner stability guarantee is active.
237 do_test like-3.3.104 {
238 set sqlite_like_count 0
239 sqlite3_db_config db QPSG 1
241 SELECT x FROM t1 WHERE x LIKE $::likepat ORDER BY 1;
243 } {abc abcd nosort {} i1}
244 do_test like-3.3.105 {
245 set sqlite_like_count
248 # The query planner stability guarantee does not disrupt explicit patterns
250 do_test like-3.3.105 {
251 set sqlite_like_count 0
253 SELECT x FROM t1 WHERE x LIKE 'abc%' ORDER BY 1;
255 } {abc abcd nosort {} i1}
256 do_test like-3.3.106 {
257 set sqlite_like_count
259 sqlite3_db_config db QPSG 0
261 # The LIKE optimization still works when the RHS is a string with no
262 # wildcard. Ticket [e090183531fc2747]
266 SELECT x FROM t1 WHERE x LIKE 'a' ORDER BY 1;
271 SELECT x FROM t1 WHERE x LIKE 'ab' ORDER BY 1;
276 SELECT x FROM t1 WHERE x LIKE 'abcd' ORDER BY 1;
278 } {abcd nosort {} i1}
281 SELECT x FROM t1 WHERE x LIKE 'abcde' ORDER BY 1;
286 # Partial optimization when the pattern does not end in '%'
289 set sqlite_like_count 0
291 SELECT x FROM t1 WHERE x LIKE 'a_c' ORDER BY 1;
295 set sqlite_like_count
298 set sqlite_like_count 0
300 SELECT x FROM t1 WHERE x LIKE 'ab%d' ORDER BY 1;
302 } {abcd abd nosort {} i1}
304 set sqlite_like_count
307 set sqlite_like_count 0
309 SELECT x FROM t1 WHERE x LIKE 'a_c%' ORDER BY 1;
311 } {abc abcd nosort {} i1}
313 set sqlite_like_count
316 # No optimization when the pattern begins with a wildcard.
317 # Note that the index is still used but only for sorting.
320 set sqlite_like_count 0
322 SELECT x FROM t1 WHERE x LIKE '%bcd' ORDER BY 1;
324 } {abcd bcd nosort {} i1}
326 set sqlite_like_count
329 # No optimization for case insensitive LIKE
332 set sqlite_like_count 0
333 db eval {PRAGMA case_sensitive_like=off;}
335 SELECT x FROM t1 WHERE x LIKE 'abc%' ORDER BY 1;
337 } {ABC {ABC abc xyz} abc abcd nosort {} i1}
339 set sqlite_like_count
342 # No optimization without an index.
345 set sqlite_like_count 0
347 PRAGMA case_sensitive_like=on;
351 SELECT x FROM t1 WHERE x LIKE 'abc%' ORDER BY 1;
353 } {abc abcd sort t1 *}
355 set sqlite_like_count
358 # No GLOB optimization without an index.
361 set sqlite_like_count 0
363 SELECT x FROM t1 WHERE x GLOB 'abc*' ORDER BY 1;
365 } {abc abcd sort t1 *}
367 set sqlite_like_count
370 # GLOB is optimized regardless of the case_sensitive_like setting.
373 set sqlite_like_count 0
374 db eval {CREATE INDEX i1 ON t1(x);}
376 SELECT x FROM t1 WHERE x GLOB 'abc*' ORDER BY 1;
378 } {abc abcd nosort {} i1}
380 set sqlite_like_count
383 set sqlite_like_count 0
384 db eval {PRAGMA case_sensitive_like=on;}
386 SELECT x FROM t1 WHERE x GLOB 'abc*' ORDER BY 1;
388 } {abc abcd nosort {} i1}
390 set sqlite_like_count
393 set sqlite_like_count 0
394 db eval {PRAGMA case_sensitive_like=off;}
396 SELECT x FROM t1 WHERE x GLOB 'a[bc]d' ORDER BY 1;
398 } {abd acd nosort {} i1}
400 set sqlite_like_count
403 # GLOB optimization when there is no wildcard. Ticket [e090183531fc2747]
407 SELECT x FROM t1 WHERE x GLOB 'a' ORDER BY 1;
412 SELECT x FROM t1 WHERE x GLOB 'abcd' ORDER BY 1;
414 } {abcd nosort {} i1}
417 SELECT x FROM t1 WHERE x GLOB 'abcde' ORDER BY 1;
423 # No optimization if the LHS of the LIKE is not a column name or
424 # if the RHS is not a string.
427 execsql {PRAGMA case_sensitive_like=on}
428 set sqlite_like_count 0
430 SELECT x FROM t1 WHERE x LIKE 'abc%' ORDER BY 1
432 } {abc abcd nosort {} i1}
434 set sqlite_like_count
437 set sqlite_like_count 0
439 SELECT x FROM t1 WHERE +x LIKE 'abc%' ORDER BY 1
441 } {abc abcd nosort {} i1}
443 set sqlite_like_count
446 set sqlite_like_count 0
448 SELECT x FROM t1 WHERE x LIKE ('ab' || 'c%') ORDER BY 1
450 } {abc abcd nosort {} i1}
452 set sqlite_like_count
455 # 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.
460 execsql {PRAGMA case_sensitive_like=off}
461 set sqlite_like_count 0
463 SELECT x FROM t1 WHERE x LIKE 'abc%' ORDER BY 1
465 } {ABC {ABC abc xyz} abc abcd nosort {} i1}
467 set sqlite_like_count
471 CREATE TABLE t2(x TEXT COLLATE NOCASE);
472 INSERT INTO t2 SELECT * FROM t1 ORDER BY rowid;
473 CREATE INDEX i2 ON t2(x COLLATE NOCASE);
475 set sqlite_like_count 0
477 SELECT x FROM t2 WHERE x LIKE 'abc%' ORDER BY 1
479 } {abc ABC {ABC abc xyz} abcd nosort {} i2}
481 set sqlite_like_count
485 PRAGMA case_sensitive_like=on;
487 set sqlite_like_count 0
489 SELECT x FROM t2 WHERE x LIKE 'abc%' ORDER BY 1
491 } {abc abcd nosort {} i2}
493 set sqlite_like_count
497 PRAGMA case_sensitive_like=off;
499 set sqlite_like_count 0
501 SELECT x FROM t2 WHERE x GLOB 'abc*' ORDER BY 1
503 } {abc abcd nosort {} i2}
505 set sqlite_like_count
508 execsql {PRAGMA case_sensitive_like=off}
509 set sqlite_like_count 0
511 SELECT x FROM t1 WHERE x LIKE 'ABC%' ORDER BY 1
513 } {ABC {ABC abc xyz} abc abcd nosort {} i1}
515 set sqlite_like_count
518 set sqlite_like_count 0
520 SELECT x FROM t2 WHERE x LIKE 'ABC%' ORDER BY 1
522 } {abc ABC {ABC abc xyz} abcd nosort {} i2}
524 set sqlite_like_count
528 PRAGMA case_sensitive_like=on;
530 set sqlite_like_count 0
532 SELECT x FROM t2 WHERE x LIKE 'ABC%' ORDER BY 1
534 } {ABC {ABC abc xyz} nosort {} i2}
536 set sqlite_like_count
540 PRAGMA case_sensitive_like=off;
542 set sqlite_like_count 0
544 SELECT x FROM t2 WHERE x GLOB 'ABC*' ORDER BY 1
546 } {ABC {ABC abc xyz} nosort {} i2}
548 set sqlite_like_count
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.
555 # Make sure this happens correctly when the last character is a
556 # "z" and we are doing case-insensitive comparisons.
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');
569 SELECT x FROM t2 WHERE x LIKE 'zz%';
571 } {zz-lower-lower zZ-lower-upper Zz-upper-lower ZZ-upper-upper nosort {} i2}
574 SELECT x FROM t2 WHERE x LIKE 'zZ%';
576 } {zz-lower-lower zZ-lower-upper Zz-upper-lower ZZ-upper-upper nosort {} i2}
579 SELECT x FROM t2 WHERE x LIKE 'Zz%';
581 } {zz-lower-lower zZ-lower-upper Zz-upper-lower ZZ-upper-upper nosort {} i2}
584 SELECT x FROM t2 WHERE x LIKE 'ZZ%';
586 } {zz-lower-lower zZ-lower-upper Zz-upper-lower ZZ-upper-upper nosort {} i2}
589 PRAGMA case_sensitive_like=on;
590 CREATE TABLE t3(x TEXT);
591 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');
598 SELECT x FROM t3 WHERE x LIKE 'zz%';
600 } {zz-lower-lower nosort {} i3}
603 SELECT x FROM t3 WHERE x LIKE 'zZ%';
605 } {zZ-lower-upper nosort {} i3}
608 SELECT x FROM t3 WHERE x LIKE 'Zz%';
610 } {Zz-upper-lower nosort {} i3}
613 SELECT x FROM t3 WHERE x LIKE 'ZZ%';
615 } {ZZ-upper-upper nosort {} i3}
620 # Make sure the LIKE prefix optimization does not strip off leading
621 # characters of the like pattern that happen to be quote characters.
624 foreach x { 'abc 'bcd 'def 'ax } {
625 set x2 '[string map {' ''} $x]'
626 db eval "INSERT INTO t2 VALUES($x2)"
629 SELECT * FROM t2 WHERE x LIKE '''a%'
635 SELECT rowid, * FROM t1 WHERE rowid GLOB '1*' ORDER BY rowid;
637 } {1 a 10 ABC 11 CDE 12 {ABC abc xyz}}
641 # Overloading the LIKE function with -1 for the number of arguments
642 # will overload both the 2-argument and the 3-argument LIKE.
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';
653 } {1 ghijkl 2 ghijkl}
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
659 SELECT 1, x FROM t8 WHERE x LIKE '%h%';
660 SELECT 2, x FROM t8 WHERE x LIKE '%h%' ESCAPE 'x';
662 } {1 ghijkl 2 ghijkl}
664 db function like -argcount 2 newlike
666 SELECT 1, x FROM t8 WHERE x LIKE '%h%';
667 SELECT 2, x FROM t8 WHERE x LIKE '%h%' ESCAPE 'x';
669 } {1 abcdef 1 ghijkl 1 mnopqr 2 ghijkl}
671 db function like -argcount 3 newlike
673 SELECT 1, x FROM t8 WHERE x LIKE '%h%';
674 SELECT 2, x FROM t8 WHERE x LIKE '%h%' ESCAPE 'x';
676 } {1 abcdef 1 ghijkl 1 mnopqr 2 abcdef 2 ghijkl 2 mnopqr}
679 ifcapable like_opt&&!icu {
680 # Evaluate SQL. Return the result set followed by the
681 # and the number of full-scan steps.
685 proc count_steps {sql} {
687 lappend r scan [db status step] sort [db status sort]
691 SELECT x FROM t2 WHERE x LIKE 'x%'
693 } {xyz scan 0 sort 0}
696 SELECT x FROM t2 WHERE x LIKE '_y%'
698 } {xyz scan 19 sort 0}
700 set res [sqlite3_exec_hex db {
701 SELECT x FROM t2 WHERE x LIKE '%78%25'
706 set res [sqlite3_exec_hex db {
707 EXPLAIN QUERY PLAN SELECT x FROM t2 WHERE x LIKE '%78%25'
709 regexp {INDEX i2} $res
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'
719 set res [sqlite3_exec_hex db {
720 SELECT substr(x,2) AS x FROM t2 WHERE x LIKE '%ff%25'
725 set res [sqlite3_exec_hex db {
726 EXPLAIN QUERY PLAN SELECT x FROM t2 WHERE x LIKE '%ff%25'
728 regexp {SCAN TABLE t2} $res
732 set res [sqlite3_exec_hex db {
733 SELECT x FROM t2 WHERE x LIKE '%fe%25'
738 set res [sqlite3_exec_hex db {
739 EXPLAIN QUERY PLAN SELECT x FROM t2 WHERE x LIKE '%fe%25'
741 regexp {INDEX i2} $res
745 # Do an SQL statement. Append the search count to the end of the result.
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]
754 # The LIKE and GLOB optimizations do not work on columns with
755 # affinity other than TEXT.
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
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);
778 SELECT a FROM t10 WHERE b LIKE '12%' ORDER BY +a;
780 } {12 123 scan 5 like 6}
783 SELECT a FROM t10 WHERE c LIKE '12%' ORDER BY +a;
785 } {12 123 scan 5 like 6}
788 SELECT a FROM t10 WHERE d LIKE '12%' ORDER BY +a;
790 } {12 123 scan 5 like 6}
793 SELECT a FROM t10 WHERE e LIKE '12%' ORDER BY +a;
795 } {12 123 scan 5 like 6}
796 ifcapable like_match_blobs {
799 SELECT a FROM t10 WHERE f LIKE '12%' ORDER BY +a;
801 } {12 123 scan 4 like 0}
805 SELECT a FROM t10 WHERE f LIKE '12%' ORDER BY +a;
807 } {12 123 scan 3 like 0}
811 SELECT a FROM t10 WHERE a LIKE '12%' ORDER BY +a;
813 } {12 123 scan 5 like 6}
817 a INTEGER PRIMARY KEY,
824 INSERT INTO t10b SELECT * FROM t10;
827 SELECT a FROM t10b WHERE b GLOB '12*' ORDER BY +a;
829 } {12 123 scan 5 like 6}
832 SELECT a FROM t10b WHERE c GLOB '12*' ORDER BY +a;
834 } {12 123 scan 5 like 6}
837 SELECT a FROM t10b WHERE d GLOB '12*' ORDER BY +a;
839 } {12 123 scan 5 like 6}
842 SELECT a FROM t10b WHERE e GLOB '12*' ORDER BY +a;
844 } {12 123 scan 5 like 6}
845 ifcapable like_match_blobs {
848 SELECT a FROM t10b WHERE f GLOB '12*' ORDER BY +a;
850 } {12 123 scan 4 like 0}
854 SELECT a FROM t10b WHERE f GLOB '12*' ORDER BY +a;
856 } {12 123 scan 3 like 0}
860 SELECT a FROM t10b WHERE a GLOB '12*' ORDER BY +a;
862 } {12 123 scan 5 like 6}
865 # LIKE and GLOB where the default collating sequence is not appropriate
866 # but an index with the appropriate collating sequence exists.
871 a INTEGER PRIMARY KEY,
872 b TEXT COLLATE nocase,
873 c TEXT COLLATE binary
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;
891 db eval {PRAGMA case_sensitive_like=OFF;}
893 SELECT b FROM t11 WHERE b LIKE 'abc%' ORDER BY a;
895 } {abc abcd ABC ABCD nosort t11 *}
897 db eval {PRAGMA case_sensitive_like=ON;}
899 SELECT b FROM t11 WHERE b LIKE 'abc%' ORDER BY a;
901 } {abc abcd nosort t11 *}
904 PRAGMA case_sensitive_like=OFF;
905 CREATE INDEX t11b ON t11(b);
908 SELECT b FROM t11 WHERE b LIKE 'abc%' ORDER BY +a;
910 } {abc abcd ABC ABCD sort {} t11b}
912 db eval {PRAGMA case_sensitive_like=ON;}
914 SELECT b FROM t11 WHERE b LIKE 'abc%' ORDER BY a;
916 } {abc abcd nosort t11 *}
919 PRAGMA case_sensitive_like=OFF;
921 CREATE INDEX t11bnc ON t11(b COLLATE nocase);
924 SELECT b FROM t11 WHERE b LIKE 'abc%' ORDER BY +a;
926 } {abc abcd ABC ABCD sort {} t11bnc}
928 db eval {CREATE INDEX t11bb ON t11(b COLLATE binary);}
930 SELECT b FROM t11 WHERE b LIKE 'abc%' ORDER BY +a;
932 } {abc abcd ABC ABCD sort {} t11bnc}
934 db eval {PRAGMA case_sensitive_like=ON;}
936 SELECT b FROM t11 WHERE b LIKE 'abc%' ORDER BY +a;
938 } {abc abcd sort {} t11bb}
940 db eval {PRAGMA case_sensitive_like=OFF;}
942 SELECT b FROM t11 WHERE b GLOB 'abc*' ORDER BY +a;
944 } {abc abcd sort {} t11bb}
947 CREATE INDEX t11cnc ON t11(c COLLATE nocase);
948 CREATE INDEX t11cb ON t11(c COLLATE binary);
951 SELECT c FROM t11 WHERE c LIKE 'abc%' ORDER BY +a;
953 } {abc abcd ABC ABCD sort {} t11cnc}
956 SELECT c FROM t11 WHERE c GLOB 'abc*' ORDER BY +a;
958 } {abc abcd sort {} t11cb}
960 # A COLLATE clause on the pattern does not change the result of a
963 do_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;
970 do_execsql_test like-12.2 {
971 SELECT id FROM t12b WHERE x LIKE 'abc%' ORDER BY +id;
973 do_execsql_test like-12.3 {
974 SELECT id FROM t12nc WHERE x LIKE 'abc%' COLLATE binary ORDER BY +id;
976 do_execsql_test like-12.4 {
977 SELECT id FROM t12b WHERE x LIKE 'abc%' COLLATE binary ORDER BY +id;
979 do_execsql_test like-12.5 {
980 SELECT id FROM t12nc WHERE x LIKE 'abc%' COLLATE nocase ORDER BY +id;
982 do_execsql_test like-12.6 {
983 SELECT id FROM t12b WHERE x LIKE 'abc%' COLLATE nocase ORDER BY +id;
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
990 do_execsql_test like-12.11 {
992 SELECT id FROM t12nc WHERE x LIKE 'abc%' ORDER BY +id;
994 do_execsql_test like-12.12 {
996 SELECT id FROM t12b WHERE x LIKE 'abc%' ORDER BY +id;
998 do_execsql_test like-12.13 {
1000 SELECT id FROM t12nc WHERE x LIKE 'abc%' COLLATE nocase ORDER BY +id;
1002 do_execsql_test like-12.14 {
1004 SELECT id FROM t12b WHERE x LIKE 'abc%' COLLATE nocase ORDER BY +id;
1006 do_execsql_test like-12.15 {
1008 SELECT id FROM t12nc WHERE x LIKE 'abc%' COLLATE binary ORDER BY +id;
1010 do_execsql_test like-12.16 {
1012 SELECT id FROM t12b WHERE x LIKE 'abc%' COLLATE binary ORDER BY +id;
1015 # Ticket [https://www.sqlite.org/src/tktview/80369eddd5c94d49f7fbbcf5]
1018 do_execsql_test like-13.1 {
1019 SELECT char(0x304d) LIKE char(0x306d);
1021 do_execsql_test like-13.2 {
1022 SELECT char(0x4d) LIKE char(0x306d);
1024 do_execsql_test like-13.3 {
1025 SELECT char(0x304d) LIKE char(0x6d);
1027 do_execsql_test like-13.4 {
1028 SELECT char(0x4d) LIKE char(0x6d);
1031 # Performance testing for patterns with many wildcards. These LIKE and GLOB
1032 # patterns were quite slow with SQLite 3.15.2 and earlier.
1035 set x [lindex [time {
1036 db one {SELECT 'aaaaaaaaaaaaaaaaaaaaaaaaaaaaaaaz'GLOB'*a*a*a*a*a*a*a*a*y'}
1038 puts -nonewline " ($x ms - want less than 1000) "
1043 set x [lindex [time {
1044 db one {SELECT 'aaaaaaaaaaaaaaaaaaaaaaaaaaaaaaaz'LIKE'%a%a%a%a%a%a%a%a%y'}
1046 puts -nonewline " ($x ms - want less than 1000) "
1052 # 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.
1057 do_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),
1065 SELECT y FROM t15 WHERE x LIKE 'ab/%d%' ESCAPE '/';
1067 do_execsql_test like-15.101 {
1069 SELECT y FROM t15 WHERE x LIKE 'ab/%d%' ESCAPE '/';
1071 do_execsql_test like-15.102 {
1073 SELECT y FROM t15 WHERE x LIKE 'ab/%d%' ESCAPE '//';
1075 do_execsql_test like-15.103 {
1077 SELECT y FROM t15 WHERE x LIKE 'ab/%d%' ESCAPE '';
1079 do_execsql_test like-15.110 {
1080 SELECT y FROM t15 WHERE x LIKE 'abcdx%%' ESCAPE 'x';
1082 do_execsql_test like-15.111 {
1083 SELECT y FROM t15 WHERE x LIKE 'abx%%' ESCAPE 'x' ORDER BY +y
1085 do_execsql_test like-15.112 {
1087 SELECT y FROM t15 WHERE x LIKE 'abx%%' ESCAPE 'x' ORDER BY +y
1089 do_execsql_test like-15.120 {
1090 SELECT y FROM t15 WHERE x LIKE '/%bc%' ESCAPE '/';
1092 do_execsql_test like-15.121 {
1094 SELECT y FROM t15 WHERE x LIKE '/%bc%' ESCAPE '/';