How to merge multiple rows into one row

  • I have a table that looks like this ...

    idtype_codephone_num

    11111-111-1111

    12222-222-2222

    21111-111-1111

    32222-222-2222

    I want to merge the data to look like this ...

    idphone1 phone2

    1111-111-1111222-222-2222

    2111-111-1111NULL

    3NULL222-222-2222

    Basically if the type code is 1 one then move the data to column phone1, if the type is 2 then move it to column phone2.

    This would be fairly simple if we always have type codes 1 and 2. But sometimes we can have type 1 and not type 2, or we could have type 2 and not type1.

    Right now we only have 2 type codes. But, in the future we could be adding a 3rd type. So that would add a 3rd column (phone3).

    Below is my code that I have written. I move the data into a temp table then list it. I am thinking of making this a view to my table. It works just fine. My question is, is there a better and more efficient way of doing this?

    CREATE TABLE #Contacts (

    id INT PRIMARY KEY,

    phone1 VARCHAR(15),

    phone2 VARCHAR(15)

    )

    -- Insert the records for type 1

    INSERT INTO #Contacts

    SELECT id,

    phone_num,

    NULL

    FROM test1

    WHERE type_code = '1'

    -- Insert the records for type 2, if the id does not exist for type 1

    INSERT INTO #Contacts

    SELECT id,

    NULL,

    phone_num

    FROM test1

    WHERE NOT EXISTS (

    SELECT 1

    FROM #Contacts

    WHERE #Contacts.id = test1.id

    )

    AND test1.type_code = '2'

    -- if the id has both type 1 and 2, update the phone2 column with the data from type 2

    UPDATE #Contacts

    SET phone2 = test1.phone_num

    FROM #contacts

    JOIN test1 ON test1.id = #Contacts.id

    WHERE type_code = '2'

    SELECT id, phone1, phone2

    FROM #Contacts

    DROP TABLE #Contacts

  • I'd vote against a denormalized table. Stick with your current design at the table level.

    If needed for an application layer you could use a pivoted view to display it in the format you described.

    Something like

    SELECT

    id,

    MAX(CASE WHEN type_code = 1 THEN phone_num ELSE NULL END) AS phone1,

    MAX(CASE WHEN type_code = 2 THEN phone_num ELSE NULL END) AS phone2

    FROM test1

    GROUP BY id



    Lutz
    A pessimist is an optimist with experience.

    How to get fast answers to your question[/url]
    How to post performance related questions[/url]
    Links for Tally Table [/url] , Cross Tabs [/url] and Dynamic Cross Tabs [/url], Delimited Split Function[/url]

  • That's perfect. So simple.

    Thank you.

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

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