Documentation Home
MySQL 5.7 Reference Manual
Related Documentation Download this Manual Excerpts from this Manual

MySQL 5.7 Reference Manual  /  ...  /  String Comparison Functions

12.5.1 String Comparison Functions

Table 12.8 String Comparison Operators

LIKE Simple pattern matching
NOT LIKE Negation of simple pattern matching
STRCMP() Compare two strings

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.

  • expr LIKE pat [ESCAPE 'escape_char']

    Pattern matching using a SQL pattern. Returns 1 (TRUE) or 0 (FALSE). If either expr or pat is NULL, the result is NULL.

    The pattern need not be a literal string. For example, it can be specified as a string expression or table column.

    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 CHAR or VARCHAR comparisons 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.

    • \% 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 empty or one character long. 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 two statements illustrate that string comparisons are not case sensitive unless one of the operands is a 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

    Because MySQL uses C escape syntax in strings (for example, \n to represent a newline character), you must double any \ that you use in LIKE strings. 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 LIKE pat [ESCAPE 'escape_char']

    This is the same as NOT (expr LIKE pat [ESCAPE 'escape_char']).


    Aggregate queries involving NOT LIKE comparisons with columns containing NULL may yield unexpected results. For example, consider the following table and data:

    CREATE TABLE foo (bar VARCHAR(10));

    The query SELECT COUNT(*) FROM foo WHERE bar LIKE '%baz%'; returns 0. You might assume that SELECT COUNT(*) FROM foo WHERE bar NOT LIKE '%baz%'; would return 2. However, this is not the case: The second query returns 0. This is because NULL NOT LIKE expr always returns NULL, regardless of the value of expr. The same is true for aggregate queries involving NULL and comparisons using NOT RLIKE or NOT REGEXP. In such cases, you must test explicitly for NOT NULL using OR (and not AND), as shown here:

    SELECT COUNT(*) FROM foo WHERE bar NOT LIKE '%baz%' OR bar IS NULL;
  • STRCMP(expr1,expr2)

    STRCMP() returns 0 if the strings are the same, -1 if the first argument is smaller than the second according to the current sort order, and 1 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, “Collation of 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 |

Download this Manual
User Comments
  Posted by Sascha René Leib on October 10, 2002
Also, keep in mind that by default,
Swedish/Finnish string comparison rules are in
use! This means that e.g.: u <> ü = y !
  Posted by Ami Chayun on January 12, 2006
It is possible to search wildchar patterns when using bind parameters.
For example to search a substring:

select * from tblUser where Name LIKE CONCAT('%', ? ,'%');

And then (for example in perl DBI)
$dbh->selectrow_hashref($SQL_Stmnt, undef, @{[ 'Erik']});

This provides a 'safer' search environment in web interfaces, since it prevents SQL injections.
  Posted by Shannon Black on January 4, 2011
Hi All

So I couldn't find any explanation how to test that a word from one table was partly in a column from the current table. Don't know if you'll make use of this but here's what I came up with:

SELECT a_table, special_table FROM a_table WHERE 'description' LIKE CONCAT('%',special_table.popular_search,'%')

Sign Up Login You must be logged in to post a comment.