|
| 1 | +IF OBJECT_ID('dbo.udf_PatReplace8K', 'IF') IS NULL |
| 2 | +EXECUTE ('CREATE FUNCTION dbo.udf_PatReplace8K() RETURNS TABLE WITH SCHEMABINDING AS RETURN SELECT 1 AS A;'); |
| 3 | +GO |
| 4 | + |
| 5 | + |
| 6 | +ALTER FUNCTION dbo.udf_PatReplace8K |
| 7 | +( |
| 8 | + @string varchar(8000), |
| 9 | + @pattern varchar(50), |
| 10 | + @replace varchar(1) |
| 11 | +) |
| 12 | +/***************************************************************************************** |
| 13 | +Purpose: |
| 14 | + Given a string (@string), a pattern (@pattern), and a replacement character (@replace) |
| 15 | + udf_PatReplace8K will replace any character in @string that matches the @pattern parameter |
| 16 | + with the character, @replace. |
| 17 | +
|
| 18 | +Usage: |
| 19 | +--===== Basic Syntax Example |
| 20 | + SELECT pr.NewString |
| 21 | + FROM dbo.udf_PatReplace8K(@string, @pattern, @replace); |
| 22 | +
|
| 23 | +--===== Replace numeric characters with a "*" |
| 24 | + SELECT pr.NewString |
| 25 | + FROM dbo.udf_PatReplace8K('My phone number is 555-2211','[0-9]','*') pr; |
| 26 | +
|
| 27 | +--==== Using againsts a table |
| 28 | + DECLARE @table TABLE(OldString varchar(40)); |
| 29 | + INSERT @table VALUES |
| 30 | + ('Call me at 555-222-6666'), |
| 31 | + ('phone number: (312)555-2323'), |
| 32 | + ('He can be reached at 444.665.4466'); |
| 33 | + SELECT t.OldString, pr.NewString |
| 34 | + FROM @table t |
| 35 | + CROSS APPLY dbo.udf_PatReplace8K(t.OldString,'[0-9]','*') pr; |
| 36 | +
|
| 37 | + Programmer Notes: |
| 38 | + 1. Required SQL Server 2008+ |
| 39 | + 2. @pattern IS case sensitive but can be easily modified to make it case insensitive |
| 40 | + 3. There is no need to include the "%" before and/or after your pattern since since we |
| 41 | + are evaluating each character individually |
| 42 | + 4. Certain special characters, such as "$" and "%" need to be escaped with a "/" |
| 43 | + like so: [/$/%] |
| 44 | +
|
| 45 | +Revision History: |
| 46 | + Rev 00 - 10/27/2014 Initial Development - Alan Burstein |
| 47 | +
|
| 48 | + Rev 01 - 10/29/2014 Mar 2007 - Alan Burstein |
| 49 | + - Redesigned based on the dbo.STRIP_NUM_EE by Eirikur Eiriksson |
| 50 | + (see: http://www.sqlservercentral.com/Forums/Topic1585850-391-2.aspx) |
| 51 | + - change how the cte tally table is created |
| 52 | + - put the include/exclude logic in a CASE statement instead of a WHERE clause |
| 53 | + - Added Latin1_General_BIN Colation |
| 54 | + - Add code to use the pattern as a parameter. |
| 55 | +
|
| 56 | + Rev 02 - 20141106 |
| 57 | + - Added final performane enhancement (more cudo's to Eirikur Eiriksson) |
| 58 | + - Put 0 = PATINDEX filter logic into the WHERE clause |
| 59 | +
|
| 60 | +Rev 03 - 20150516 |
| 61 | + - Updated to deal with special XML characters |
| 62 | +
|
| 63 | +Rev 04 - 20170320 |
| 64 | + - changed @replace from char(1) to varchar(1) to address how spaces are handled |
| 65 | +*****************************************************************************************/ |
| 66 | +RETURNS TABLE WITH SCHEMABINDING |
| 67 | +AS |
| 68 | +RETURN |
| 69 | +WITH |
| 70 | +E1(N) AS (SELECT N FROM (VALUES (1),(1),(1),(1),(1),(1),(1),(1),(1),(1)) AS E1(N)), |
| 71 | +iTally(N) AS |
| 72 | +( |
| 73 | + SELECT TOP (LEN(@string)) CHECKSUM(ROW_NUMBER() OVER (ORDER BY (SELECT NULL))) |
| 74 | + FROM E1 a,E1 b,E1 c,E1 d |
| 75 | +) |
| 76 | +SELECT NewString = |
| 77 | +(( |
| 78 | + SELECT |
| 79 | + CASE |
| 80 | + WHEN PATINDEX(@pattern,SUBSTRING(@string COLLATE Latin1_General_BIN,N,1)) = 0 |
| 81 | + THEN SUBSTRING(@string,N,1) |
| 82 | + ELSE @replace |
| 83 | + END |
| 84 | + FROM iTally |
| 85 | + FOR XML PATH(''), TYPE |
| 86 | +).value('.[1]','varchar(8000)')); |
| 87 | +GO |
0 commit comments