Categories:

String & Binary Functions (Matching/Comparison)

[ NOT ] LIKE¶

Performs a case-sensitive comparison to determine whether a string matches or does not match a specified pattern. For case-insensitive matching, use ILIKE instead.

LIKE, ILIKE, and RLIKE all perform similar operations. However, RLIKE uses POSIX ERE (Extended Regular Expression) syntax instead of the SQL pattern syntax used by LIKE and ILIKE.

Tip

You can use the search optimization service to improve the performance of queries that call this function. For details, see Search Optimization Service.

See also:

[ NOT ] ILIKE , [ NOT ] RLIKE , LIKE ALL, LIKE ANY

Syntax¶

<subject> [ NOT ] LIKE <pattern> [ ESCAPE <escape> ]

LIKE( <subject> , <pattern> [ , <escape> ] )
Copy

Arguments¶

Required:

subject

Subject to match. This is typically a VARCHAR, although some other data types can be used.

pattern

Pattern to match. This is typically a VARCHAR, although some other data types can be used.

Optional:

escape

Character(s) inserted in front of a wildcard character to indicate that the wildcard should be interpreted as a regular character and not as a wildcard.

Returns¶

Returns a BOOLEAN or NULL.

  • When LIKE is specified, the value is TRUE if there is a match. Otherwise, returns FALSE.

  • When NOT LIKE is specified, the value is TRUE if there is no match. Otherwise, returns FALSE.

  • When either LIKE or NOT LIKE is specified, returns NULL if any argument is NULL.

Usage Notes¶

  • SQL wildcards are supported in pattern:

    • An underscore (_) matches any single character.

    • A percent sign (%) matches any sequence of zero or more characters.

  • Wildcards in pattern include newline characters (n) in subject as matches.

  • LIKE pattern matching covers the entire string. To match a sequence anywhere within a string, start and end the pattern with %.

  • NULL does not match NULL. In other words, if the subject is NULL and the pattern is NULL, that is not considered a match.

  • There is no default escape character.

  • If you use the backslash as an escape character, then you must specify escape the backslash in the ESCAPE clause. For example, the following command specifies that the escape character is the backslash, and then uses that escape character to search for ‘%’ as a literal (without the escape character, the ‘%’ would be treated as a wildcard):

    'SOMETHING%' LIKE '%\\%%' ESCAPE '\\';
    
    Copy

    For examples of using escape characters, and in particular the backslash as an escape character, see Examples.

Collation details¶

Only the upper, lower, and trim collation specifications are supported. Combinations with upper, lower, and trim are also supported (for example, upper-trim and lower-trim), except for locale combinations (for example, en-upper).

Note

To use this function with a column that has the upper, lower, or trim collation specifiers, you must enable the 2024_02 behavior change bundle in your account.

To enable this bundle in your account, execute the following statement:

SELECT SYSTEM$ENABLE_BEHAVIOR_CHANGE_BUNDLE('2024_02');
Copy

Examples¶

The following examples show the use of LIKE, NOT LIKE, and the wildcard character %:

CREATE OR REPLACE TABLE like_ex(name VARCHAR(20));
INSERT INTO like_ex VALUES
    ('John  Dddoe'),
    ('Joe   Doe'),
    ('John_down'),
    ('Joe down'),
    ('Elaine'),
    (''),    -- empty string
    (null);
Copy
SELECT name
    FROM like_ex
    WHERE name LIKE '%Jo%oe%'
    ORDER BY name;
Copy
+-------------+                                                                 
| NAME        |
|-------------|
| Joe   Doe   |
| John  Dddoe |
+-------------+
SELECT name
    FROM like_ex
    WHERE name NOT LIKE '%Jo%oe%'
    ORDER BY name;
Copy
+-----------+
| NAME      |
|-----------|
|           |
| Elaine    |
| Joe down  |
| John_down |
+-----------+
SELECT name
    FROM like_ex
    WHERE name LIKE '%J%h%^_do%' ESCAPE '^'
    ORDER BY name;
Copy
+-----------+                                                                   
| NAME      |
|-----------|
| John_down |
+-----------+
SELECT name
    FROM like_ex
    WHERE name NOT LIKE 'John%'
    ORDER BY name;
Copy
+-----------+                                                                   
| NAME      |
|-----------|
|           |
| Elaine    |
| Joe   Doe |
| Joe down  |
+-----------+
SELECT name
    FROM like_ex
    WHERE name NOT LIKE ''
    ORDER BY name;
Copy
+-------------+                                                                 
| NAME        |
|-------------|
| Elaine      |
| Joe   Doe   |
| Joe down    |
| John  Dddoe |
| John_down   |
+-------------+

The following example uses an ESCAPE clause:

INSERT INTO like_ex (name) VALUES 
    ('100 times'),
    ('1000 times'),
    ('100%');
Copy

Without the escape character, the percent sign (‘%’) is treated as a wildcard:

SELECT * FROM like_ex WHERE name LIKE '100%'
    ORDER BY 1;
Copy
+------------+                                                                  
| NAME       |
|------------|
| 100 times  |
| 100%       |
| 1000 times |
+------------+

With the escape character, the percent sign (‘%’) is treated as a literal:

SELECT * FROM like_ex WHERE name LIKE '100^%' ESCAPE '^'
    ORDER BY 1;
Copy
+------+                                                                        
| NAME |
|------|
| 100% |
+------+

The following example uses an ESCAPE clause in which the backslash is the escape character. Note that the backslash itself must be escaped in both the ESCAPE clause and in the expression:

SELECT * FROM like_ex WHERE name LIKE '100\\%' ESCAPE '\\'
    ORDER BY 1;
Copy
+------+                                                                        
| NAME |
|------|
| 100% |
+------+