REPLACE (Transact-SQL)
Replaces all occurrences of a specified string value with another string value.
Transact-SQL Syntax Conventions
Syntax
REPLACE ( string_expression , string_pattern , string_replacement )
Arguments
string_expression
Is the string expression to be searched. string_expression can be of a character or binary data type.string_pattern
Is the substring to be found. string_pattern can be of a character or binary data type. string_pattern cannot be an empty string (''), and must not exceed the maximum number of bytes that fits on a page.string_replacement
Is the replacement string. string_replacement can be of a character or binary data type.
Return Types
Returns nvarchar if one of the input arguments is of the nvarchar data type; otherwise, REPLACE returns varchar.
Returns NULL if any one of the arguments is NULL.
If string_expression is not of type varchar(max) or nvarchar(max), REPLACE truncates the return value at 8,000 bytes. To return values greater than 8,000 bytes, string_expression must be explicitly cast to a large-value data type.
Remarks
REPLACE performs comparisons based on the collation of the input. To perform a comparison in a specified collation, you can use COLLATE to apply an explicit collation to the input.
0x0000 (char(0)) is an undefined character in Windows collations and cannot be included in REPLACE.
Examples
The following example replaces the string cde in abcdefghi with xxx.
SELECT REPLACE('abcdefghicde','cde','xxx');
GO
Here is the result set.
------------
abxxxfghixxx
(1 row(s) affected)
The following example uses the COLLATE function.
SELECT REPLACE('Das ist ein Test' COLLATE Latin1_General_BIN,
'Test', 'desk' );
GO
Here is the result set.
------------
Das ist ein desk
(1 row(s) affected)