Update Table with Join NOT RBAR

  • Hello,

    My problem today is that when this company started they had no standards for data entry. So one person could enter Alabama and another Al while a third AL. I have identified 12 tables with a state column and these tables may have records of this nature. We now have a standard for entering states as the two letter abbreviation. So my task is to find situations such as Alabama and update it to AL.

    I know I don't want to do this RBAR so I was thinking of doing it with a Join but I'm not sure how to update with a join. Would my control table have two colums? Column A would be the incorrect way and column B would be the correct way? We would use column A to join on and column B to update to the correct value?

    What about situations that I can't think ahead to match such as a typo where Alabamma does not match anything. Is there a way to have one entry in the control join table that is a wildcard and append a GOOFY_ so that I can then query for GOOFY and zap the odd balls?

    Thnaks for pointing me in the right direction

    JB

  • nfs_john (10/30/2012)


    Hello,

    My problem today is that when this company started they had no standards for data entry. So one person could enter Alabama and another Al while a third AL. I have identified 12 tables with a state column and these tables may have records of this nature. We now have a standard for entering states as the two letter abbreviation. So my task is to find situations such as Alabama and update it to AL.

    I know I don't want to do this RBAR so I was thinking of doing it with a Join but I'm not sure how to update with a join. Would my control table have two colums? Column A would be the incorrect way and column B would be the correct way? We would use column A to join on and column B to update to the correct value?

    What about situations that I can't think ahead to match such as a typo where Alabamma does not match anything. Is there a way to have one entry in the control join table that is a wildcard and append a GOOFY_ so that I can then query for GOOFY and zap the odd balls?

    Thnaks for pointing me in the right direction

    JB

    Kudos for realizing that RBAR is not the best approach here. I tossed together an example of how you could do this. It would be far easier if we had your ddl to work with but this should show at least one way to do it.

    create table #BadData

    (

    BadState varchar(25),

    ST char(2)

    )

    insert #BadData

    select 'Alabama', null union all

    select 'AL', null union all

    select 'Alabadma', null

    create table #StateLookup

    (

    ST char(2),

    StateName varchar(50)

    )

    insert #StateLookup

    select 'AK', 'Alaska' union all

    select 'AL', 'Alabama' union all

    select 'AR', 'Arkansas' union all

    select 'AZ', 'Arizona' union all

    select 'CA', 'California' union all

    select 'CO', 'Colorado' union all

    select 'CT', 'Connecticut' union all

    select 'DC', 'District Of Columbia' union all

    select 'DE', 'Delaware' union all

    select 'FL', 'Florida' union all

    select 'GA', 'Georgia' union all

    select 'HI', 'Hawaii' union all

    select 'IA', 'Iowa' union all

    select 'ID', 'Idaho' union all

    select 'IL', 'Illinois' union all

    select 'IN', 'Indiana' union all

    select 'KS', 'Kansas' union all

    select 'KY', 'Kentucky' union all

    select 'LA', 'Louisiana' union all

    select 'MA', 'Massachusetts' union all

    select 'MD', 'Maryland' union all

    select 'ME', 'Maine' union all

    select 'MI', 'Michigan' union all

    select 'MN', 'Minnesota' union all

    select 'MO', 'Missouri' union all

    select 'MS', 'Mississippi' union all

    select 'MT', 'Montana' union all

    select 'NC', 'North Carolina' union all

    select 'ND', 'North Dakota' union all

    select 'NE', 'Nebraska' union all

    select 'NH', 'New Hampshire' union all

    select 'NJ', 'New Jersey' union all

    select 'NM', 'New Mexico' union all

    select 'NV', 'Nevada' union all

    select 'NY', 'New York' union all

    select 'OH', 'Ohio' union all

    select 'OK', 'Oklahoma' union all

    select 'OR', 'Oregon' union all

    select 'PA', 'Pennsylvania' union all

    select 'RI', 'Rhode Island' union all

    select 'SC', 'South Carolina' union all

    select 'SD', 'South Dakota' union all

    select 'TN', 'Tennessee' union all

    select 'TX', 'Texas' union all

    select 'UT', 'Utah' union all

    select 'VA', 'Virginia' union all

    select 'VT', 'Vermont' union all

    select 'WA', 'Washington' union all

    select 'WI', 'Wisconsin' union all

    select 'WV', 'West Virginia' union all

    select 'WY', 'Wyoming'

    select *

    from #BadData bd

    left join #StateLookup sl on sl.ST = bd.BadState or sl.StateName = bd.BadState

    update #BadData

    set ST = sl.ST

    from #BadData bd

    left join #StateLookup sl on sl.ST = bd.BadState or sl.StateName = bd.BadState

    --But what about the ones that didn't find a match???

    select * from #BadData where ST is null

    drop table #BadData

    drop table #StateLookup

    _______________________________________________________________

    Need help? Help us help you.

    Read the article at http://www.sqlservercentral.com/articles/Best+Practices/61537/ for best practices on asking questions.

    Need to split a string? Try Jeff Modens splitter http://www.sqlservercentral.com/articles/Tally+Table/72993/.

    Cross Tabs and Pivots, Part 1 – Converting Rows to Columns - http://www.sqlservercentral.com/articles/T-SQL/63681/
    Cross Tabs and Pivots, Part 2 - Dynamic Cross Tabs - http://www.sqlservercentral.com/articles/Crosstab/65048/
    Understanding and Using APPLY (Part 1) - http://www.sqlservercentral.com/articles/APPLY/69953/
    Understanding and Using APPLY (Part 2) - http://www.sqlservercentral.com/articles/APPLY/69954/

  • Mr. Lange,

    Sorry for the delay I was pulled off to another fire before coming back to this project. As for this question and answer I don't see where to mark as an answer or give you credit but your post provided enough to jog my memory back into RDBM & TSQL world. I created my update tables and executed the joins. It all worked quite nicely.

    THANK YOU

    JB

  • nfs_john (11/26/2012)


    Mr. Lange,

    Sorry for the delay I was pulled off to another fire before coming back to this project. As for this question and answer I don't see where to mark as an answer or give you credit but your post provided enough to jog my memory back into RDBM & TSQL world. I created my update tables and executed the joins. It all worked quite nicely.

    THANK YOU

    JB

    Glad that worked for you. Around here we don't have a mechanism for "Mark as Answer" or that type of thing. All threads remain open because there may be somebody else who comes along and has a different approach to the same issue that is better than the posted "answer". As far as credit...well you just gave it to me by your comment. Thanks for letting me know that worked and as always feel free to post here or start a new thread when you find yourself in need of help in the future.

    _______________________________________________________________

    Need help? Help us help you.

    Read the article at http://www.sqlservercentral.com/articles/Best+Practices/61537/ for best practices on asking questions.

    Need to split a string? Try Jeff Modens splitter http://www.sqlservercentral.com/articles/Tally+Table/72993/.

    Cross Tabs and Pivots, Part 1 – Converting Rows to Columns - http://www.sqlservercentral.com/articles/T-SQL/63681/
    Cross Tabs and Pivots, Part 2 - Dynamic Cross Tabs - http://www.sqlservercentral.com/articles/Crosstab/65048/
    Understanding and Using APPLY (Part 1) - http://www.sqlservercentral.com/articles/APPLY/69953/
    Understanding and Using APPLY (Part 2) - http://www.sqlservercentral.com/articles/APPLY/69954/

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

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