12.8.1 String Comparison Functions and Operators (original) (raw)

12.8.1 String Comparison Functions and Operators

Table 12.13 String Comparison Functions and Operators

Name Description
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.

If a string function is invoked from within themysql 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”.

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:

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.

mysql> SELECT 'David!' LIKE 'David\_';  
        -> 0  
mysql> SELECT 'David_' LIKE 'David\_';  
        -> 1  

To specify a different escape character, use theESCAPE 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 theNO_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 permitsLIKE on numeric expressions.

mysql> SELECT 10 LIKE '1%';  
        -> 1  

MySQL attempts in such cases to perform implicit conversion of the expression to a string. SeeSection 12.3, “Type Conversion in Expression Evaluation”.
Note
MySQL uses C escape syntax in strings (for example,\n to represent the newline character). If you want a LIKE 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 |  
+--------------+-----------------------+  
CREATE TABLE foo (bar VARCHAR(10));  
INSERT INTO foo VALUES (NULL), (NULL);  

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 return2. However, this is not the case: The second query returns 0. This is becauseNULL NOT LIKE_`expr`_ always returnsNULL, regardless of the value of_expr_. The same is true for aggregate queries involving NULL and comparisons usingNOT RLIKE or NOT REGEXP. In such cases, you must test explicitly for NOT NULL usingOR (and notAND), as shown here:

SELECT COUNT(*) FROM foo WHERE bar NOT LIKE '%baz%' OR bar IS NULL;  
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. SeeSection 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 |  
+--------------------------------------------+