SQL Query - Update varchar ID's...confused.com

  • Hi,

    So I have been replacing an old database of ours with a new one - it has all gone relatively well. The new database structure etc is far better, far more effecient and well awesome. unfortunately something I couldn't change was the ID structure ( the users wanted the same data presented to them a lot better).

    My problem - I have had to rename tables/queries/stored procedures/triggers to follow a new convention, which is fine, unfortunately I would "really" like to change 1 tables ID:

    Sample ID's:

    AG001/1/P1

    AG002/1/P1

    AG003/1/P1

    AG004/1/P1

    AG006/1/P1

    AG007/1/PO1

    AG008/1/P01

    AG009/1/P01

    AG010/1/P01

    AL001/1/P1

    AL002/1/P1

    AL003/1/P1

    CC013/1/P01

    As you can see they are a pain in the..It basically mirrors three tiers (each tier is a section between the slashes). I would like to change the ID's in the final tier to the following:

    AG001/1/L1

    AG002/1/L1

    AG003/1/L1

    AG004/1/L1

    AG006/1/L1

    AG007/1/LO1

    AG008/1/L01

    AG009/1/L01

    AG010/1/L01

    AL001/1/L1

    AL002/1/L1

    AL003/1/L1

    CC013/1/L01

    I find this quite difficult to explain, the first XX000 is the 1st tier, the /1/ is the second tier and the X01 or X1 or X001 is the final tier (the final tier is the messiest due to human error). Unfortauntely there are too many records to edit manually. I have tried looking into using CHARINDEX/REPLACE/SUBSTR which are helpful - the following provides me with the final tier which I then need to edit - however how can I go and edit to the new format.

    Used in a cursor:RIGHT(@ID, CHARINDEX('/', REVERSE(ID)) - 1)

    I have also thought about simply recreating the final tier ID's from scratch, so they all follow Lnnn - this would be neater but again I unfortauntely don't know how to do this using SQL?

    Now I hold the 2nd tiers ID in another column

    AG001/1

    AG002/1

    AG003/1

    AG004/1

    AG006/1

    AG007/1

    AG008/1

    AG009/1

    AG010/1

    AL001/1

    AL002/1

    AL003/1

    CC013/1

    Perfect results:

    AG001/1/L001

    AG001/2/L001

    AG001/2/L002

    AG001/2/L003

    CE001/1/L001

    CE002/1/L001

  • ok, if you are sure there is always three sections to your ID's, here's one way to do it:

    with myCTE (ID)

    AS

    (

    SELECT 'AG001/1/P1' UNION ALL

    SELECT 'AG002/1/P1' UNION ALL

    SELECT 'AG003/1/P1' UNION ALL

    SELECT 'AG004/1/P1' UNION ALL

    SELECT 'AG006/1/P1' UNION ALL

    SELECT 'AG007/1/PO1' UNION ALL

    SELECT 'AG008/1/P01' UNION ALL

    SELECT 'AG009/1/P01' UNION ALL

    SELECT 'AG010/1/P01' UNION ALL

    SELECT 'AL001/1/P1' UNION ALL

    SELECT 'AL002/1/P1' UNION ALL

    SELECT 'AL003/1/P1' UNION ALL

    SELECT 'CC013/1/P01')

    SELECT

    PARSENAME(REPLACE(ID,'/','.'),3) As Tier1,

    PARSENAME(REPLACE(ID,'/','.'),2) As Tier2,

    PARSENAME(REPLACE(ID,'/','.'),1) As Tier3

    FROM myCTE

    and you could consider putting calculated columns on your table to make the teirs a little easier to access:

    ALTER TABLE MYTABLE ADD Tier1 AS PARSENAME(REPLACE(ID,'/','.'),3) PERSISTED

    ALTER TABLE MYTABLE ADD Tier2 AS PARSENAME(REPLACE(ID,'/','.'),2) PERSISTED

    ALTER TABLE MYTABLE ADD Tier3 AS PARSENAME(REPLACE(ID,'/','.'),1) PERSISTED

    Lowell


    --help us help you! If you post a question, make sure you include a CREATE TABLE... statement and INSERT INTO... statement into that table to give the volunteers here representative data. with your description of the problem, we can provide a tested, verifiable solution to your question! asking the question the right way gets you a tested answer the fastest way possible!

  • You appear to have a violation of normal form by storing more than one piece of data in a single column. I think, ideally, you would want a table that had each piece of information stored in it's own column.

    Col1, Col2, Col3

    AL003, 1, P1

    CC013, 1, P01

    Etc...

    The application that uses this data could then either access it through a stored procedure or view:

    CREATE VIEW dbo.something

    AS

    SELECT Col1 + '/' + Col2 + '/' + Col3

    FROM table

    GO

    And the results of querying dbo.something would look like...

    AL003/1/P1

    CC013/1/P01

    Another option would be to create a computed column on the table that would concatenate the three data.

    But to answer your question, I think you want an update that looks something like this?

    UPDATE table

    SET columnname=PARSENAME(replace(columnname,'/','.'),3)

    + '/'

    + PARSENAME(replace(columnname,'/','.'),2)

    + '/'

    + REPLACE(PARSENAME(replace(columnname,'/','.'),1), 'P', 'L')

    It's messy and that is an artifact of trying to tease out the different pieces of data stored in the column.

  • If I wanted to replace the id structure (to clean up the data) to the form Lnnn (AG001/1/L001 etc) - is there a way I could do this.

    I realise I would wipe the current ID's and then use my 2nd tier ID column (AG001/1) to build the new ID....

    So for each ID in column "as_id" create a new id in column ld_id suffixing a 3 digit incremental number on the end of L.......When the as_id changes reset the increment to 0...so it would look like this (in an ideal world):

    LD_ID COLUMN AS_ID COLUMN

    AG001/1/L001 AG001/1

    AG001/1/L002 AG001/1

    AG001/1/L003 AG001/1

    AG001/2/L001 AG001/1

    AG001/2/L002 AG001/1

    CE001/1/L001 CE001/1

  • oops i missed that part;

    doing something like SELECT RIGHT('0000' + SomeString,3) will give you stuff like 002 with preceeding zeros;

    then it's the find and replace you were after.

    i think this slices up teh peices, so you can decide how you wnat them reassembled:

    with myCTE (ID)

    AS

    (

    SELECT 'AG001/1/P1' UNION ALL

    SELECT 'AG002/1/P1' UNION ALL

    SELECT 'AG003/1/P1' UNION ALL

    SELECT 'AG004/1/P1' UNION ALL

    SELECT 'AG006/1/P1' UNION ALL

    SELECT 'AG007/1/PO1' UNION ALL

    SELECT 'AG008/1/P01' UNION ALL

    SELECT 'AG009/1/P01' UNION ALL

    SELECT 'AG010/1/P01' UNION ALL

    SELECT 'AL001/1/P1' UNION ALL

    SELECT 'AL002/1/P1' UNION ALL

    SELECT 'AL003/1/P1' UNION ALL

    SELECT 'CC013/1/P01')

    SELECT

    PARSENAME(REPLACE(ID,'/','.'),3) As Tier1,

    PARSENAME(REPLACE(ID,'/','.'),2) As Tier2,

    'L' + RIGHT('000' + REPLACE(REPLACE(PARSENAME(REPLACE(ID,'/','.'),1),'P','') ,'L',''),3) As Tier3

    FROM myCTE

    Lowell


    --help us help you! If you post a question, make sure you include a CREATE TABLE... statement and INSERT INTO... statement into that table to give the volunteers here representative data. with your description of the problem, we can provide a tested, verifiable solution to your question! asking the question the right way gets you a tested answer the fastest way possible!

Viewing 5 posts - 1 through 4 (of 4 total)

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