October 16, 2012 at 12:31 am
I have a table TXNS
Column A is int (3)
Column B is varchar 10
I wish to remove all non-alphanumeric characters from Column B
using a tally table.
Lets set a limit of 20 rows to the tally table.
Any ideas?
October 16, 2012 at 1:01 am
PatIndex can be used
October 16, 2012 at 1:12 am
sj999 (10/16/2012)
I have a table TXNSColumn A is int (3)
Column B is varchar 10
I wish to remove all non-alphanumeric characters from Column B
using a tally table.
Lets set a limit of 20 rows to the tally table.
Any ideas?
You only need 10 rows, because your B column is VARCHAR(10).
Here's the sample data I used: -
SELECT X AS A, N AS B
INTO TXNS
FROM (VALUES(1,'r^$%^edsad'),(2,'fwsa38#'))a(X,N);
And here's the solution: -
WITH Tally(N) AS (SELECT ROW_NUMBER() OVER(ORDER BY (SELECT NULL))
FROM(VALUES(0),(0),(0),(0),(0),(0),(0),(0),(0),(0))a(N))
SELECT a.A, a.B, (SELECT stripped
FROM TXNS b
CROSS APPLY (SELECT CASE WHEN PATINDEX('[A-Za-z0-9]',SUBSTRING(B,N,1)) = 1
THEN SUBSTRING(B,N,1)
ELSE '' END
FROM Tally
WHERE N <= LEN(B)) c(stripped)
WHERE a.A = b.A
FOR XML PATH(''), TYPE
).value('.', 'VARCHAR(10)') AS stripped
FROM TXNS a;
Note that I've used an inline CTE tally table rather than a physical one. This can be replaced if required.
October 16, 2012 at 3:08 am
Nice. I would have thought it the same way 🙂 But I think the self join can be omitted
;WITH Tally(N) AS (SELECT ROW_NUMBER() OVER(ORDER BY (SELECT NULL))
FROM(VALUES(0),(0),(0),(0),(0),(0),(0),(0),(0),(0))a(N))
SELECT A,B,stripped
FROM TXNS b
CROSS APPLY (SELECT (SELECT CASE WHEN PATINDEX('[A-Za-z0-9]',SUBSTRING(B,N,1)) = 1
THEN SUBSTRING(B,N,1)
ELSE '' END
FROM Tally
WHERE N <= LEN(B)
FOR XML PATH(''), TYPE
).value('.', 'VARCHAR(10)') ) c(stripped)
For easier readability we can omit TYPE and value combination as well as we are dealing with only alphanumeric values.
October 16, 2012 at 8:44 pm
All these methods using [A-Za-z0-9] recognise 139 characters (with the Latin1_General_ci_as collation).
Now personally I think that's right (although it's a rather complicated pattern to use for the job), but I have met a lot of people (all Americans, I think) who claim that there are only 62 alphanumeric characters and lose their cool when anyone suggests that there are more; I guess these people must insist on using the bin collation instead of a dictionary one, and use the complicated pattern because the simple one delivers 75 characters even with the bin collation.
Tom
October 16, 2012 at 11:36 pm
L' Eomot Inversé (10/16/2012)
All these methods using [A-Za-z0-9] recognise 139 characters (with the Latin1_General_ci_as collation).Now personally I think that's right (although it's a rather complicated pattern to use for the job), but I have met a lot of people (all Americans, I think) who claim that there are only 62 alphanumeric characters and lose their cool when anyone suggests that there are more; I guess these people must insist on using the bin collation instead of a dictionary one, and use the complicated pattern because the simple one delivers 75 characters even with the bin collation.
There are only 62 alphanumeric characters. The others in your signature don't count. 😛
My thought question: Have you ever been told that your query runs too fast?
My advice:
INDEXing a poor-performing query is like putting sugar on cat food. Yeah, it probably tastes better but are you sure you want to eat it?
The path of least resistance can be a slippery slope. Take care that fixing your fixes of fixes doesn't snowball and end up costing you more than fixing the root cause would have in the first place.
Need to UNPIVOT? Why not CROSS APPLY VALUES instead?[/url]
Since random numbers are too important to be left to chance, let's generate some![/url]
Learn to understand recursive CTEs by example.[/url]
[url url=http://www.sqlservercentral.com/articles/St
Viewing 6 posts - 1 through 5 (of 5 total)
You must be logged in to reply to this topic. Login to reply