Identify Bad Characters in a Table Column

  • Comments posted to this topic are about the item Identify Bad Characters in a Table Column


    My mantra: No loops! No CURSORs! No RBAR! Hoo-uh![/I]

    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

  • Interpreting the results from this isn't straightforward, at least not to me. I prefer the output formatted like this:

    SELECT Strings, x.Goodchars, y.Badchars

    FROM #t

    CROSS APPLY (

    SELECT SUBSTRING(Strings,n,1)

    FROM (SELECT TOP (DATALENGTH(Strings)) n = ROW_NUMBER() OVER(ORDER BY @@SPID) FROM sys.columns a, sys.columns b) n

    WHERE SUBSTRING(Strings,n,1) LIKE '%[a-zA-Z0-9]%'

    FOR XML PATH('')

    ) x (Goodchars)

    CROSS APPLY (

    SELECT SUBSTRING(Strings,n,1)

    FROM (SELECT TOP (DATALENGTH(Strings)) n = ROW_NUMBER() OVER(ORDER BY @@SPID) FROM sys.columns a, sys.columns b) n

    WHERE SUBSTRING(Strings,n,1) LIKE '%[^a-zA-Z0-9]%'

    FOR XML PATH('')

    ) y (Badchars)

    Otherwise, an interesting article. Putting ^ into the @allowed string was a bit naughty ๐Ÿ˜‰

    โ€œWrite the query the simplest way. If through testing it becomes clear that the performance is inadequate, consider alternative query forms.โ€ - Gail Shaw

    For fast, accurate and documented assistance in answering your questions, please read this article.
    Understanding and using APPLY, (I) and (II) Paul White
    Hidden RBAR: Triangular Joins / The "Numbers" or "Tally" Table: What it is and how it replaces a loop Jeff Moden

  • ChrisM@Work (5/8/2012)


    Interpreting the results from this isn't straightforward, at least not to me. I prefer the output formatted like this:

    SELECT Strings, x.Goodchars, y.Badchars

    FROM #t

    CROSS APPLY (

    SELECT SUBSTRING(Strings,n,1)

    FROM (SELECT TOP (DATALENGTH(Strings)) n = ROW_NUMBER() OVER(ORDER BY @@SPID) FROM sys.columns a, sys.columns b) n

    WHERE SUBSTRING(Strings,n,1) LIKE '%[a-zA-Z0-9]%'

    FOR XML PATH('')

    ) x (Goodchars)

    CROSS APPLY (

    SELECT SUBSTRING(Strings,n,1)

    FROM (SELECT TOP (DATALENGTH(Strings)) n = ROW_NUMBER() OVER(ORDER BY @@SPID) FROM sys.columns a, sys.columns b) n

    WHERE SUBSTRING(Strings,n,1) LIKE '%[^a-zA-Z0-9]%'

    FOR XML PATH('')

    ) y (Badchars)

    Otherwise, an interesting article. Putting ^ into the @allowed string was a bit naughty ๐Ÿ˜‰

    Hey! To each his own. There's probably 20 or more ways to do this one and probably many that perform better. Your suggestion is also good.

    Personally, I love playing with recursive CTEs, almost as much as I like being naughty, just to figure out how they work. ๐Ÿ˜›

    I always hear people saying "stay away from recursive CTEs because they're slow" so I like to fall back on a classical education:

    โ€œIf you know the enemy and know yourself, you need not fear the result of a hundred battles. If you know yourself but not the enemy, for every victory gained you will also suffer a defeat. If you know neither the enemy nor yourself, you will succumb in every battleโ€

    ? Sun Tzu, The Art of War, Special Edition


    My mantra: No loops! No CURSORs! No RBAR! Hoo-uh![/I]

    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

  • dwain.c (5/9/2012)


    ...Personally, I love playing with recursive CTEs, almost as much as I like being naughty, just to figure out how they work. ๐Ÿ˜›

    I always hear people saying "stay away from recursive CTEs because they're slow" ...

    Play is an excellent way to learn - I love to play with the problems folks post on here (far too little time these days). Here's a few examples of rCTE's to whet your appetite:

    Paul White's Super-fast DISTINCT

    Calculating interest rate

    Handshaking

    Running total with a twist

    Sequence-numbering groups

    Calculate volume percentages

    Have fun!

    Cheers

    ChrisM

    โ€œWrite the query the simplest way. If through testing it becomes clear that the performance is inadequate, consider alternative query forms.โ€ - Gail Shaw

    For fast, accurate and documented assistance in answering your questions, please read this article.
    Understanding and using APPLY, (I) and (II) Paul White
    Hidden RBAR: Triangular Joins / The "Numbers" or "Tally" Table: What it is and how it replaces a loop Jeff Moden

  • -- Along the same lines, this is a very simple way of listing invalid data (allowing -_,;@' in the email column)

    DECLARE @match VARCHAR(30)

    SET @match = '%[^a-zA-Z0-9@.,;!-!_!'''']%'

    SELECT email

    FROM tbl_Staff

    WHERE email IS NOT NULL

    AND email LIKE @match ESCAPE '!'

    ORDER BY email

  • stephen.sarre (5/10/2012)


    -- Along the same lines, this is a very simple way of listing invalid data (allowing -_,;@' in the email column)

    DECLARE @match VARCHAR(30)

    SET @match = '%[^a-zA-Z0-9@.,;!-!_!'''']%'

    SELECT email

    FROM tbl_Staff

    WHERE email IS NOT NULL

    AND email LIKE @match ESCAPE '!'

    ORDER BY email

    Yep - that's a bit of a simpler problem.

    In my case, I built the CTE to INSERT those bad characters into a temporary table, which I then used to construct a dynamic SQL UPDATE that replaced all the bad characters with ''. The second part ran really, really fast.


    My mantra: No loops! No CURSORs! No RBAR! Hoo-uh![/I]

    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

  • Thanks for the script.

Viewing 7 posts - 1 through 6 (of 6 total)

You must be logged in to reply to this topic. Login to reply