There are three separate approaches to pattern matching
provided by PostgreSQL: the
traditional SQL LIKE
operator, the more recent SQL99 SIMILAR
TO
operator, and POSIX-style regular expressions.
Additionally, a pattern matching function, SUBSTRING
, is available, using either
SQL99-style or POSIX-style
regular expressions.
Tip: If you have pattern matching needs that go beyond this, consider writing a user-defined function in Perl or Tcl.
LIKE
string LIKE pattern [ESCAPE escape-character] string NOT LIKE pattern [ESCAPE escape-character]
Every pattern defines a set
of strings. The LIKE
expression
returns true if the string is
contained in the set of strings represented by pattern. (As expected, the NOT LIKE
expression returns false if
LIKE
returns true, and vice
versa. An equivalent expression is NOT
(string LIKE pattern).)
If pattern does not contain
percent signs or underscore, then the pattern only represents
the string itself; in that case LIKE
acts like the equals operator. An
underscore (_) in pattern stands for (matches) any single
character; a percent sign (%) matches
any string of zero or more characters.
Some examples:
'abc' LIKE 'abc' true 'abc' LIKE 'a%' true 'abc' LIKE '_b_' true 'abc' LIKE 'c' false
LIKE
pattern matches always
cover the entire string. To match a pattern anywhere within a
string, the pattern must therefore start and end with a percent
sign.
To match a literal underscore or percent sign without matching other characters, the respective character in pattern must be preceded by the escape character. The default escape character is the backslash but a different one may be selected by using the ESCAPE clause. To match the escape character itself, write two escape characters.
Note that the backslash already has a special meaning in
string literals, so to write a pattern constant that contains a
backslash you must write two backslashes in the query. Thus,
writing a pattern that actually matches a literal backslash
means writing four backslashes in the query. You can avoid this
by selecting a different escape character with ESCAPE; then backslash is not special to
LIKE
anymore. (But it is still
special to the string literal parser, so you still need two of
them.)
It's also possible to select no escape character by writing ESCAPE ''. This effectively disables the escape mechanism, which makes it impossible to turn off the special meaning of underscore and percent signs in the pattern.
The keyword ILIKE can be used instead of LIKE to make the match case insensitive according to the active locale. This is not in the SQL standard but is a PostgreSQL extension.
The operator ~~ is equivalent to
LIKE
, and ~~* corresponds to ILIKE
. There are also !~~ and !~~* operators
that represent NOT LIKE
and
NOT ILIKE
. All of these operators
are PostgreSQL-specific.
SIMILAR
TO
and SQL99 Regular
Expressionsstring SIMILAR TO pattern [ESCAPE escape-character] string NOT SIMILAR TO pattern [ESCAPE escape-character]
The SIMILAR TO
operator
returns true or false depending on whether its pattern matches
the given string. It is much like LIKE
, except that it interprets the pattern
using SQL99's definition of
a regular expression. SQL99's regular expressions are a curious
cross between LIKE
notation and
common regular expression notation.
Like LIKE
, the SIMILAR TO
operator succeeds only if its
pattern matches the entire string; this is unlike common
regular expression practice, wherein the pattern may match any
part of the string. Also like LIKE
, SIMILAR
TO
uses % and _ as wildcard characters denoting any string and
any single character, respectively (these are comparable to
.* and . in
POSIX regular expressions).
In addition to these facilities borrowed from LIKE
, SIMILAR
TO
supports these pattern-matching metacharacters
borrowed from POSIX regular expressions:
| denotes alternation (either of two alternatives).
* denotes repetition of the previous item zero or more times.
+ denotes repetition of the previous item one or more times.
Parentheses () may be used to group items into a single logical item.
A bracket expression [...] specifies a character class, just as in POSIX regular expressions.
Notice that bounded repetition (? and {...}) are not provided, though they exist in POSIX. Also, dot (.) is not a metacharacter.
As with LIKE
, a backslash
disables the special meaning of any of these metacharacters; or
a different escape character can be specified with ESCAPE.
Some examples:
'abc' SIMILAR TO 'abc' true 'abc' SIMILAR TO 'a' false 'abc' SIMILAR TO '%(b|d)%' true 'abc' SIMILAR TO '(b|c)%' false
The SUBSTRING
function with
three parameters, SUBSTRING(
, provides extraction of a
substring that matches a SQL99 regular expression pattern. As
with SIMILAR TO, the specified pattern
must match to the entire data string, else the function fails
and returns null. To indicate the part of the pattern that
should be returned on success, SQL99 specifies that the pattern
must contain two occurrences of the escape character followed
by double quote ("). The text matching
the portion of the pattern between these markers is
returned.string
FROM pattern FOR escape)
Some examples:
SUBSTRING('foobar' FROM '%#"o_b#"%' FOR '#') oob SUBSTRING('foobar' FROM '#"o_b#"%' FOR '#') NULL
Table 6-11 lists the available operators for pattern matching using POSIX regular expressions.
Table 6-11. Regular Expression Match Operators
Operator | Description | Example |
---|---|---|
~ | Matches regular expression, case sensitive | 'thomas' ~ '.*thomas.*' |
~* | Matches regular expression, case insensitive | 'thomas' ~* '.*Thomas.*' |
!~ | Does not match regular expression, case sensitive | 'thomas' !~ '.*Thomas.*' |
!~* | Does not match regular expression, case insensitive | 'thomas' !~* '.*vadim.*' |
POSIX regular expressions
provide a more powerful means for pattern matching than the
LIKE
and SIMILAR TO
operators. Many Unix tools such as
egrep, sed,
or awk use a pattern matching language
that is similar to the one described here.
A regular expression is a character sequence that is an
abbreviated definition of a set of strings (a regular set). A string is said to match a
regular expression if it is a member of the regular set
described by the regular expression. As with LIKE
, pattern characters match string
characters exactly unless they are special characters in the
regular expression language --- but regular expressions use
different special characters than LIKE
does. Unlike LIKE
patterns, a regular expression is
allowed to match anywhere within a string, unless the regular
expression is explicitly anchored to the beginning or end of
the string.
Some examples:
'abc' ~ 'abc' true 'abc' ~ '^a' true 'abc' ~ '(b|d)' true 'abc' ~ '^(b|c)' false
The SUBSTRING
function with
two parameters, SUBSTRING(
, provides extraction of a
substring that matches a POSIX regular expression pattern. It
returns null if there is no match, otherwise the portion of the
text that matched the pattern. But if the pattern contains any
parentheses, the portion of the text that matched the first
parenthesized subexpression (the one whose left parenthesis
comes first) is returned. You can always put parentheses around
the whole expression if you want to use parentheses within it
without triggering this exception.string
FROM pattern)
Some examples:
SUBSTRING('foobar' FROM 'o.b') oob SUBSTRING('foobar' FROM 'o(.)b') o
Regular expressions (REs), as defined in POSIX 1003.2, come in two forms: modern REs (roughly those of egrep; 1003.2 calls these "extended" REs) and obsolete REs (roughly those of ed; 1003.2 "basic" REs). PostgreSQL implements the modern form.
A (modern) RE is one or more non-empty branches, separated by |. It matches anything that matches one of the branches.
A branch is one or more pieces, concatenated. It matches a match for the first, followed by a match for the second, etc.
A piece is an atom possibly followed by a single *, +, ?, or bound. An atom followed by * matches a sequence of 0 or more matches of the atom. An atom followed by + matches a sequence of 1 or more matches of the atom. An atom followed by ? matches a sequence of 0 or 1 matches of the atom.
A bound is { followed by an unsigned decimal integer, possibly followed by , possibly followed by another unsigned decimal integer, always followed by }. The integers must lie between 0 and RE_DUP_MAX (255) inclusive, and if there are two of them, the first may not exceed the second. An atom followed by a bound containing one integer i and no comma matches a sequence of exactly i matches of the atom. An atom followed by a bound containing one integer i and a comma matches a sequence of i or more matches of the atom. An atom followed by a bound containing two integers i and j matches a sequence of i through j (inclusive) matches of the atom.
Note: A repetition operator (?, *, +, or bounds) cannot follow another repetition operator. A repetition operator cannot begin an expression or subexpression or follow ^ or |.
An atom is a regular expression enclosed in () (matching a match for the regular expression), an empty set of () (matching the null string), a bracket expression (see below), . (matching any single character), ^ (matching the null string at the beginning of the input string), $ (matching the null string at the end of the input string), a \ followed by one of the characters ^.[$()|*+?{\ (matching that character taken as an ordinary character), a \ followed by any other character (matching that character taken as an ordinary character, as if the \ had not been present), or a single character with no other significance (matching that character). A { followed by a character other than a digit is an ordinary character, not the beginning of a bound. It is illegal to end an RE with \.
Note that the backslash (\) already has a special meaning in string literals, so to write a pattern constant that contains a backslash you must write two backslashes in the query.
A bracket expression is a list of characters enclosed in []. It normally matches any single character from the list (but see below). If the list begins with ^, it matches any single character (but see below) not from the rest of the list. If two characters in the list are separated by -, this is shorthand for the full range of characters between those two (inclusive) in the collating sequence, e.g. [0-9] in ASCII matches any decimal digit. It is illegal for two ranges to share an endpoint, e.g. a-c-e. Ranges are very collating-sequence-dependent, and portable programs should avoid relying on them.
To include a literal ] in the list, make it the first character (following a possible ^). To include a literal -, make it the first or last character, or the second endpoint of a range. To use a literal - as the first endpoint of a range, enclose it in [. and .] to make it a collating element (see below). With the exception of these and some combinations using [ (see next paragraphs), all other special characters, including \, lose their special significance within a bracket expression.
Within a bracket expression, a collating element (a character, a multiple-character sequence that collates as if it were a single character, or a collating-sequence name for either) enclosed in [. and .] stands for the sequence of characters of that collating element. The sequence is a single element of the bracket expression's list. A bracket expression containing a multiple-character collating element can thus match more than one character, e.g. if the collating sequence includes a ch collating element, then the RE [[.ch.]]*c matches the first five characters of chchcc.
Within a bracket expression, a collating element enclosed in [= and =] is an equivalence class, standing for the sequences of characters of all collating elements equivalent to that one, including itself. (If there are no other equivalent collating elements, the treatment is as if the enclosing delimiters were [. and .].) For example, if o and ^ are the members of an equivalence class, then [[=o=]], [[=^=]], and [o^] are all synonymous. An equivalence class may not be an endpoint of a range.
Within a bracket expression, the name of a character class enclosed in [: and :] stands for the list of all characters belonging to that class. Standard character class names are: alnum, alpha, blank, cntrl, digit, graph, lower, print, punct, space, upper, xdigit. These stand for the character classes defined in ctype. A locale may provide others. A character class may not be used as an endpoint of a range.
There are two special cases of bracket expressions: the bracket expressions [[:<:]] and [[:>:]] match the null string at the beginning and end of a word respectively. A word is defined as a sequence of word characters which is neither preceded nor followed by word characters. A word character is an alnum character (as defined by ctype) or an underscore. This is an extension, compatible with but not specified by POSIX 1003.2, and should be used with caution in software intended to be portable to other systems.
In the event that an RE could match more than one substring of a given string, the RE matches the one starting earliest in the string. If the RE could match more than one substring starting at that point, it matches the longest. Subexpressions also match the longest possible substrings, subject to the constraint that the whole match be as long as possible, with subexpressions starting earlier in the RE taking priority over ones starting later. Note that higher-level subexpressions thus take priority over their lower-level component subexpressions.
Match lengths are measured in characters, not collating elements. A null string is considered longer than no match at all. For example, bb* matches the three middle characters of abbbc, (wee|week)(knights|nights) matches all ten characters of weeknights, when (.*).* is matched against abc the parenthesized subexpression matches all three characters, and when (a*)* is matched against bc both the whole RE and the parenthesized subexpression match the null string.
If case-independent matching is specified, the effect is much as if all case distinctions had vanished from the alphabet. When an alphabetic that exists in multiple cases appears as an ordinary character outside a bracket expression, it is effectively transformed into a bracket expression containing both cases, e.g. x becomes [xX]. When it appears inside a bracket expression, all case counterparts of it are added to the bracket expression, so that (e.g.) [x] becomes [xX] and [^x] becomes [^xX].
There is no particular limit on the length of REs, except insofar as memory is limited. Memory usage is approximately linear in RE size, and largely insensitive to RE complexity, except for bounded repetitions. Bounded repetitions are implemented by macro expansion, which is costly in time and space if counts are large or bounded repetitions are nested. An RE like, say, ((((a{1,100}){1,100}){1,100}){1,100}){1,100} will (eventually) run almost any existing machine out of swap space. [1]
[1] |
This was written in 1994, mind you. The numbers have probably changed, but the problem persists. |