If a string function is given a binary string as an argument, the resulting string is also a binary string. A number converted to a string is treated as a binary string. This affects only comparisons.
Normally, if any expression in a string comparison is case-sensitive, the comparison is performed in case-sensitive fashion.
If a string function is invoked from within the
mysql client, binary strings display using
hexadecimal notation, depending on the value of the
--binary-as-hex
. For more
information about that option, see Section 4.5.1, “mysql — The MySQL Command-Line Client”.
expr
LIKEpat
[ESCAPE 'escape_char
']Pattern matching using an SQL pattern. Returns
1
(TRUE
) or0
(FALSE
). If eitherexpr
orpat
isNULL
, the result isNULL
.The pattern need not be a literal string. For example, it can be specified as a string expression or table column. In the latter case, the column must be defined as one of the MySQL string types (see Section 11.3, “String Data Types”).
Per the SQL standard,
LIKE
performs matching on a per-character basis, thus it can produce results different from the=
comparison operator:mysql> SELECT 'ä' LIKE 'ae' COLLATE latin1_german2_ci; +-----------------------------------------+ | 'ä' LIKE 'ae' COLLATE latin1_german2_ci | +-----------------------------------------+ | 0 | +-----------------------------------------+ mysql> SELECT 'ä' = 'ae' COLLATE latin1_german2_ci; +--------------------------------------+ | 'ä' = 'ae' COLLATE latin1_german2_ci | +--------------------------------------+ | 1 | +--------------------------------------+
In particular, trailing spaces are significant, which is not true for comparisons of nonbinary strings (
CHAR
,VARCHAR
, andTEXT
values) performed with the=
operator:mysql> SELECT 'a' = 'a ', 'a' LIKE 'a '; +------------+---------------+ | 'a' = 'a ' | 'a' LIKE 'a ' | +------------+---------------+ | 1 | 0 | +------------+---------------+ 1 row in set (0.00 sec)
With
LIKE
you can use the following two wildcard characters in the pattern:%
matches any number of characters, even zero characters._
matches exactly one character.
mysql> SELECT 'David!' LIKE 'David_'; -> 1 mysql> SELECT 'David!' LIKE '%D%v%'; -> 1
To test for literal instances of a wildcard character, precede it by the escape character. If you do not specify the
ESCAPE
character,\
is assumed, unless theNO_BACKSLASH_ESCAPES
SQL mode is enabled. In that case, no escape character is used.\%
matches one%
character.\_
matches one_
character.
mysql> SELECT 'David!' LIKE 'David\_'; -> 0 mysql> SELECT 'David_' LIKE 'David\_'; -> 1
To specify a different escape character, use the
ESCAPE
clause:mysql> SELECT 'David_' LIKE 'David|_' ESCAPE '|'; -> 1
The escape sequence should be one character long to specify the escape character, or empty to specify that no escape character is used. The expression must evaluate as a constant at execution time. If the
NO_BACKSLASH_ESCAPES
SQL mode is enabled, the sequence cannot be empty.The following statements illustrate that string comparisons are not case-sensitive unless one of the operands is case-sensitive (uses a case-sensitive collation or is a binary string):
mysql> SELECT 'abc' LIKE 'ABC'; -> 1 mysql> SELECT 'abc' LIKE _latin1 'ABC' COLLATE latin1_general_cs; -> 0 mysql> SELECT 'abc' LIKE _latin1 'ABC' COLLATE latin1_bin; -> 0 mysql> SELECT 'abc' LIKE BINARY 'ABC'; -> 0
As an extension to standard SQL, MySQL permits
LIKE
on numeric expressions.mysql> SELECT 10 LIKE '1%'; -> 1
MySQL attempts in such cases to perform implicit conversion of the expression to a string. See Section 12.3, “Type Conversion in Expression Evaluation”.
NoteMySQL uses C escape syntax in strings (for example,
\n
to represent the newline character). If you want aLIKE
string to contain a literal\
, you must double it. (Unless theNO_BACKSLASH_ESCAPES
SQL mode is enabled, in which case no escape character is used.) For example, to search for\n
, specify it as\\n
. To search for\
, specify it as\\\\
; this is because the backslashes are stripped once by the parser and again when the pattern match is made, leaving a single backslash to be matched against.Exception: At the end of the pattern string, backslash can be specified as
\\
. At the end of the string, backslash stands for itself because there is nothing following to escape. Suppose that a table contains the following values:mysql> SELECT filename FROM t1; +--------------+ | filename | +--------------+ | C: | | C:\ | | C:\Programs | | C:\Programs\ | +--------------+
To test for values that end with backslash, you can match the values using either of the following patterns:
mysql> SELECT filename, filename LIKE '%\\' FROM t1; +--------------+---------------------+ | filename | filename LIKE '%\\' | +--------------+---------------------+ | C: | 0 | | C:\ | 1 | | C:\Programs | 0 | | C:\Programs\ | 1 | +--------------+---------------------+ mysql> SELECT filename, filename LIKE '%\\\\' FROM t1; +--------------+-----------------------+ | filename | filename LIKE '%\\\\' | +--------------+-----------------------+ | C: | 0 | | C:\ | 1 | | C:\Programs | 0 | | C:\Programs\ | 1 | +--------------+-----------------------+
expr
NOT LIKEpat
[ESCAPE 'escape_char
']This is the same as
NOT (
.expr
LIKEpat
[ESCAPE 'escape_char
'])NoteAggregate queries involving
NOT LIKE
comparisons with columns containingNULL
may yield unexpected results. For example, consider the following table and data:CREATE TABLE foo (bar VARCHAR(10)); INSERT INTO foo VALUES (NULL), (NULL);
The query
SELECT COUNT(*) FROM foo WHERE bar LIKE '%baz%';
returns0
. You might assume thatSELECT COUNT(*) FROM foo WHERE bar NOT LIKE '%baz%';
would return2
. However, this is not the case: The second query returns0
. This is becauseNULL NOT LIKE
always returnsexpr
NULL
, regardless of the value ofexpr
. The same is true for aggregate queries involvingNULL
and comparisons usingNOT RLIKE
orNOT REGEXP
. In such cases, you must test explicitly forNOT NULL
usingOR
(and notAND
), as shown here:SELECT COUNT(*) FROM foo WHERE bar NOT LIKE '%baz%' OR bar IS NULL;
STRCMP()
returns0
if the strings are the same,-1
if the first argument is smaller than the second according to the current sort order, and1
otherwise.mysql> SELECT STRCMP('text', 'text2'); -> -1 mysql> SELECT STRCMP('text2', 'text'); -> 1 mysql> SELECT STRCMP('text', 'text'); -> 0
STRCMP()
performs the comparison using the collation of the arguments.mysql> SET @s1 = _latin1 'x' COLLATE latin1_general_ci; mysql> SET @s2 = _latin1 'X' COLLATE latin1_general_ci; mysql> SET @s3 = _latin1 'x' COLLATE latin1_general_cs; mysql> SET @s4 = _latin1 'X' COLLATE latin1_general_cs; mysql> SELECT STRCMP(@s1, @s2), STRCMP(@s3, @s4); +------------------+------------------+ | STRCMP(@s1, @s2) | STRCMP(@s3, @s4) | +------------------+------------------+ | 0 | 1 | +------------------+------------------+
If the collations are incompatible, one of the arguments must be converted to be compatible with the other. See Section 10.8.4, “Collation Coercibility in Expressions”.
mysql> SELECT STRCMP(@s1, @s3); ERROR 1267 (HY000): Illegal mix of collations (latin1_general_ci,IMPLICIT) and (latin1_general_cs,IMPLICIT) for operation 'strcmp' mysql> SELECT STRCMP(@s1, @s3 COLLATE latin1_general_ci); +--------------------------------------------+ | STRCMP(@s1, @s3 COLLATE latin1_general_ci) | +--------------------------------------------+ | 0 | +--------------------------------------------+