Updating Rows

  • I have three tables with user data in them. The formatting might be off but hopefully below should give you the relation.

    Users Table
    UserID    | FirstName  | LastName  | MiddleName
    1            | Some         | Dude         | Big
    2            | Another      | Dude         | Little

    UDF Table
    UserID  | FieldNo  | Value
    1          | 1           | 123456
    1          | 2           | Text1
    1          | 3           | 01/01/2018
    1          | 4           | Text2
    1          | 5           | Text3
    2          | 1           | 234567
    2          | 2           | Value1
    2          | 3           | 12/12/2012
    2          | 4           | Value2
    2          | 5           | Value3

    UserImport Table (Created for this sole purpose)
    UserID  | FirstName  | LastName  | MiddleName  | UDF1     | UDF2    | UDF3             | UDF4    | UDF5
    1          | Some        | Dude          | Big               | 123456   | Text1    | 01/01/2018     | Text2     | Text3
    2          | Another     | Dude          | Little             | 234567   | Value1  | 12/12/2012     | Value2   | Value3

    Iā€™m using SSIS to parse information coming into these tables.  An example would be that UserId 1 will have a change to the UDF2 and UDF3 fields. I bring the information into the UserImport table and was planning on doing an update to the UDF table from there.  I cannot seem to get my head wrapped around updating the un-pivoted table.  How do I update the row instead of the column?  Below is as close as I could get and I think what I have is way off.  Any help would be greatly appreciated.

    Update UDF
      SET
           Value = CASE WHEN FieldNo = 2 Then (Select UDF3 From UsersImport )
                        WHEN FieldNo = 3 Then (Select UDF3 From UsersImport)
                         END
      Where UDF.UserID = (Select UserID FROM UserImport)


  • create table users
    (
    userid int,
    firstname varchar(25),
    lastname varchar(25),
    middlename varchar(25)
    );

    insert into users values (1,'some','dude','big');

    create table udf
    (
    userid int,
    fieldno int,
    [value] varchar(25)
    );

    insert into udf values (1,1,123456);
     insert into udf values (1,2,'text1'); create table userimport
     (
      userid int,
    firstname varchar(25),
    lastname varchar(25),
    middlename varchar(25),
      udf1 varchar(25),
      udf2 varchar(25),
      udf3 varchar(25),
      udf4 varchar(25),
      udf5 varchar(25),
      )

    Kindly confirm whether it is working or not as i  was doing it in SQL fiddle


    update userimport
    set
    userid =a.userid,
    firstname=a.firstname,
    lastname=a.lastname,
    middlename=a.middlename,
    udf1= case when b.fieldno=1 then [value] end ,
    udf2= case when b.fieldno=2 then [value] end
    from
    users a inner join udf b on a.userid=b.userid

    Saravanan

  • I believe your update query works but I didn't explain well enough that the I am trying to update the UDF table and not the UserImport table.  To be specific I am trying to update the Value column.  Below is my latest failed attempt.  I'm starting to have my doubts about using CASE due to need for different information in the same column.  Thanks for any additional insight.

    Update F
        Set
        [Value] = CASE WHEN F.UserID = I.UserID and F.FieldNo = 1 then I.UDF1
                        WHEN F.UserID = I.UserID and F.FieldNo = 2 then I.UDF2
                        WHEN F.UserID = I.UserID and F.FieldNo = 3 then I.UDF3
                    END
        FROM UDF as F INNER JOIN Users as U
                ON U.UserId = F.UserID INNER JOIN UserImport as I
                ON I.UserID = F.UserID and I.UDF1 = F.[Value] WHERE F.FieldNo = 1

  • what i have done is to  convert the records in userimport from columns as rows first.
    ie (udf1, udf2, ...) is converted as
    userid,fieldno,value
    1 , 1 , New1
    1 , 2 , New2
    1 , 3 , New3
    1 , 4 , New4
    1 , 5 , New5

    So the result of that step would be how we want the final output to look like.

    This is followed by a update using join with the result set in step 1 with the udf table on the keys userid,fieldno.
    (You could also accomplish the same using MERGE statement as well)


    create table users
    (
    userid int,
    firstname varchar(25),
    lastname varchar(25),
    middlename varchar(25)
    );

    insert into users values (1,'some','dude','big');

    create table udf(userid int,fieldno int, value varchar(25));

    insert into udf values (1,1,'123456');
    insert into udf values (1,2,'text1');

    create table userimport
    (
    userid int
    ,firstname varchar(25)
    ,lastname varchar(25)
    ,middlename varchar(25)
    ,udf1 varchar(25)
    ,udf2 varchar(25)
    ,udf3 varchar(25)
    ,udf4 varchar(25)
    ,udf5 varchar(25)
    );

    insert into userimport values(1,'some','dude','big','New1','New2','New3','New4','New5');

    update a2
        set a2.value=b2.value1
       from udf a2
       join (select a.userid
                   ,b.rnk as fieldno
                   ,case when b.rnk=1 then a.udf1
                        when b.rnk=2 then a.udf2
                        when b.rnk=3 then a.udf3
                        when b.rnk=4 then a.udf4
                        when b.rnk=5 then a.udf5
                    end as Value1 
                from userimport a
                join (select top 5 row_number() over(order by (select null)) as rnk
                        from information_schema.tables
                     )b
                  on 1=1
             )b2
           on a2.userid=b2.userid
          and a2.fieldno=b2.fieldno; 
      
    select *
      from udf;

  • You are a genius, George.  That seems to work very well. Thanks for your help.

  • Cool. Glad i could help šŸ™‚

  • This should be enough to UPDATE the udf table:


    UPDATE udf
    SET Value = CASE udf.fieldno WHEN 1 THEN udf1 WHEN 2 THEN udf2 WHEN 3 THEN udf3
      WHEN 4 THEN udf4 WHEN 5 THEN udf5 END
    FROM udf
    INNER JOIN UserImport UI ON UI.userid = udf.userid

    Full example: 

    use tempdb;
    create table users
    (
    userid int,
    firstname varchar(25),
    lastname varchar(25),
    middlename varchar(25)
    );

    insert into users values (1,'some','dude','big');

    create table udf(userid int,fieldno int, value varchar(25));

    insert into udf values (1,1,'123456');
    insert into udf values (1,2,'text1');
    insert into udf values (1,3,'01/01/2018');
    insert into udf values (1,4,'Text2');
    insert into udf values (1,5,'Text3');

    create table userimport
    (
    userid int
    ,firstname varchar(25)
    ,lastname varchar(25)
    ,middlename varchar(25)
    ,udf1 varchar(25)
    ,udf2 varchar(25)
    ,udf3 varchar(25)
    ,udf4 varchar(25)
    ,udf5 varchar(25)
    );

    insert into userimport values(1,'some','dude','big','New1','New2','New3','New4','New5');

    SELECT 'Before', * FROM udf

    UPDATE udf
    SET Value = CASE udf.fieldno WHEN 1 THEN udf1 WHEN 2 THEN udf2 WHEN 3 THEN udf3
      WHEN 4 THEN udf4 WHEN 5 THEN udf5 END
    FROM udf
    INNER JOIN UserImport UI ON UI.userid = udf.userid

    SELECT 'After', * FROM udf

    drop table users
    drop table udf
    drop table userimport

    SQL DBA,SQL Server MVP(07, 08, 09) A socialist is someone who will give you the shirt off *someone else's* back.

  • Nice one , that is a better and simple solution than mine.

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

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