Removing '.' in SQL server table

  • Hi All,

    We have a table say TableA. It has a column 'Detail' which is varchar(250). I has some values with '.' in end and some without '.' Example (Row 1 : 'ADB', Row2 : 'ADC. DCD.' Row3 : 'ADC.')

    We need to remove the '.' which is occurring only in the last of 'Detail' column and load it. Example after removing '.' (Row 1: 'ADB', Row2 : 'ADC. DCD', Row3 : 'ADC')

    Database is SQL Server 2008 R2 and we are inserting into the TableA using a INSERT INTO 'SELECT' query..

    Please suggest.

    Thanks

    Jim

  • DECLARE @myRow VARCHAR(10) = 'ADC. DCD.';

    SELECT ISNULL(REVERSE(STUFF(REVERSE(@myRow),CHARINDEX('.',REVERSE(@myRow),1),1,'')),@myRow);

    ps: please read the first link in my signature on how to post questions (table DDL, sample data, desired output). It will help you to get correct answers more quicker.

    Need an answer? No, you need a question
    My blog at https://sqlkover.com.
    MCSE Business Intelligence - Microsoft Data Platform MVP

  • Thanks Koen!! This is perfect. But now there is a small change, there should not be any special character at the end. Could you please suggest..

  • Maybe something like this would help.

    WITH SampleData(String) AS(

    SELECT 'ADB' UNION ALL SELECT 'ADC. DCD.' UNION ALL SELECT 'ADC.'

    )

    SELECT CASE WHEN RIGHT( String, 1) LIKE '[^A-Za-z0-9]'

    THEN LEFT( String, LEN( String) - 1)

    ELSE String END

    FROM SampleData

    Do you have more than one special character at the end? Could you give some sample data?

    Luis C.
    General Disclaimer:
    Are you seriously taking the advice and code from someone from the internet without testing it? Do you at least understand it? Or can it easily kill your server?

    How to post data/code on a forum to get the best help: Option 1 / Option 2
  • Hi Luis,

    I think this is not working properly when the column is ending with space ' '.

    Sample data

    'ABC DS.'

    'AD.'

    'DG@'

    'DGC DS '

    'fdsf fs/'

    'fs fds //'

  • Here's a modification.

    WITH SampleData(String) AS(

    SELECT 'ADB' UNION ALL SELECT

    'ADC. DCD.' UNION ALL SELECT

    'ADC.' UNION ALL SELECT

    'ABC DS.' UNION ALL SELECT

    'AD.' UNION ALL SELECT

    'DG@' UNION ALL SELECT

    'DGC DS ' UNION ALL SELECT

    'fdsf fs/' UNION ALL SELECT

    'fs fds //'

    )

    SELECT CASE WHEN RIGHT( RTRIM(String), 1) LIKE '[^A-Za-z0-9]'

    THEN LEFT( String, LEN( String) - PATINDEX('%[A-Za-z0-9]%', REVERSE(String)) + 1)

    ELSE String END

    FROM SampleData

    Luis C.
    General Disclaimer:
    Are you seriously taking the advice and code from someone from the internet without testing it? Do you at least understand it? Or can it easily kill your server?

    How to post data/code on a forum to get the best help: Option 1 / Option 2
  • If the requirement is to remove trailing spaces and all trailing non-alpha-numerics Luis code is what's needed; but it seems a bit heavyweight if the requirement is just to eliminate trailing spaces and at most one '.'. If the requirement is just spaces and at most one '.' this simpler code will do instead:

    FROM SampleData;

    WITH SampleData(String) AS(

    SELECT 'ADB' UNION ALL SELECT

    'ADC. DCD.' UNION ALL SELECT

    'ADC.' UNION ALL SELECT

    'ABC DS.' UNION ALL SELECT

    'AD.' UNION ALL SELECT

    'DG@' UNION ALL SELECT

    'DGC DS ' UNION ALL SELECT

    'fdsf fs/' UNION ALL SELECT

    'fs fds //'

    )select CASE WHEN right( rtrim(String), 1) ='.'

    THEN rtrim(substring(String,1,len(String)-1))

    ELSE rtrim(String) END as NewString

    FROM SampleData;

    Tom

  • Thanks Luis. It worked!!

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

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