Using Update with SET joining on 2 tables not producing correct results

  • Hi,

    I have 2 tables:

    Table1

    Fields: name, dob, dos, ssn, ssn_match, dob_match, dos_match

    Table2

    Fields: name, dob, ssn

    I need to update Table A based on matches between A & B. See below for my code (that's not working correctly)

    UPDATE Table1

    SET Table1.DOS_MATCH='Y' WHERE DOS_MATCH IS NULL AND Table1.DOS IN

    (SELECT A.DOS FROM Table1 A inner JOIN Table2 B

    ON A.SSN=B.SSN

    AND A.DOS=B.DOS)

    I'm getting mixed results but why would I ever get a DOS_Match=Y when there is no matching SSN in Table2??

  • You can try it like this:

    DECLARE @TableA TABLE (name VARCHAR(50), dob DATETIME, dos DATETIME, ssn VARCHAR(9)

    ,ssn_match CHAR(1), dob_match CHAR(1), dos_match CHAR(1))

    DECLARE @TableB TABLE (name VARCHAR(50), dob DATETIME, ssn VARCHAR(9))

    INSERT INTO @TableA (name, dob, dos, ssn)

    SELECT 'Bob', '2000-06-18', '2012-06-18', '111111111'

    UNION ALL SELECT 'Sam', '2000-06-17', '2012-06-17', '222222222'

    INSERT INTO @TableB (name, dob, ssn)

    SELECT 'Bob', '2000-06-18', '111111111'

    UPDATE A

    SET dos_match = 'Y'

    FROM @TableA A

    INNER JOIN @TableB B ON A.SSN=B.SSN AND A.DOB=B.DOB

    SELECT *

    FROM @TableA


    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

Viewing 2 posts - 1 through 2 (of 2 total)

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