REGEXP_REPLACE (Transact-SQL)
Applies to:
Azure SQL Database
SQL database in Microsoft Fabric
Note
As a preview feature, the technology presented in this article is subject to Supplemental Terms of Use for Microsoft Azure Previews.
Returns a modified source string replaced by a replacement string, where the occurrence of the regular expression pattern found. If no matches are found, the function returns the original string.
REGEXP_REPLACE
(
string_expression,
pattern_expression [, string_replacement [, start [, occurrence [, flags ] ] ] ]
)
Arguments
string_expression
An expression of a character string.
Can be a constant, variable, or column of character string.
Data types: char, nchar, varchar, or nvarchar.
pattern_expression
Regular expression pattern to match. Usually a text literal
Data types: char, nchar, varchar, or nvarchar. pattern_expression
supports a maximum character length of 8,000 bytes.
string_replacement
String expression that specifies the replacement string for matching substrings and replaces the substrings matched by the pattern. The string_replacement can be of char, varchar, nchar, and nvarchar datatypes. If an empty string (' '
) is specified, the function removes all matched patterns and returns the resulting string. The default replacement string is the empty string (' '
).
The string_replacement can contain \n, where n is 1 through 9, to indicate that the source substring matching the n'th parenthesized group (subexpression) of the pattern should be inserted, and it can contain &
to indicate that the substring matching the entire pattern should be inserted. Write \ if you need to put a literal backslash in the replacement text.
For example
REGEXP_REPLACE('123-456-7890', '(\d{3})-(\d{3})-(\d{4})', '(\1) \2-\3')
Returns:
(123) 456-7890
If the provided \n
in string_replacement
is greater than the number of groups in the pattern_expression
, then the function ignores the value.
For example:
REGEXP_REPLACE('123-456-7890', '(\d{3})-(\d{3})-(\d{4})', '(\1) (\4)-xxxx')
Returns:
(123) ()-xxxx
start
Specify the starting position for the search within the search string. Optional. Type is int or bigint.
The numbering is 1-based, meaning the first character in the expression is 1
and the value must be >= 1
. If the start expression is less than 1
, returns error. If the start expression is greater than the length of string_expression
, the function returns string_expression
. The default is 1
.
occurrence
An expression (positive integer) that specifies which occurrence of the pattern expression within the source string to be searched or replaced. Default is 1
. Searches at the first character of the string_expression
. For a positive integer n
, it searches for the nth
occurrence beginning with the first character following the first occurrence of the pattern_expression
, and so forth.
flags
One or more characters that specify the modifiers used for searching for matches. Type is varchar or char, with a maximum of 30 characters.
For example, ims
. The default is c
. If an empty string (' ')
is provided, it will be treated as the default value ('c')
. Supply c
or any other character expressions. If flag contains multiple contradictory characters, then SQL Server uses the last character.
For example, if you specify ic
the regex returns case-sensitive matching.
If the value contains a character other than those listed at Supported flag values, the query returns an error like the following example:
Invalid flag provided. '<invalid character>' are not valid flags. Only {c,i,s,m} flags are valid.
Supported flag values
Flag | Description |
---|---|
i | Case-insensitive (default false) |
m | Multi-line mode: ^ and $ match begin/end line in addition to begin/end text (default false) |
s | Let . match \n (default false) |
c | Case-insensitive (default true) |
Return value
Expression.
Examples
Replace all occurrences of a
or e
with X
in the product names.
SELECT REGEXP_REPLACE (PRODUCT_NAME, '[ae]', 'X', 1, 0, 'i') FROM PRODUCTS;
Replace the first occurrence of cat
or dog
with pet
in the product descriptions
SELECT REGEXP_REPLACE (PRODUCT_DESCRIPTION, 'cat|dog', 'pet', 1, 1, 'i') FROM PRODUCTS;
Replace the last four digits of the phone numbers with asterisks
SELECT REGEXP_REPLACE (PHONE_NUMBER, '\d{4}$', '****') FROM CUSTOMERS;