Incrementing Existing Column Values

  • I need to insert new rows in a table that has a column for sequence number values (attrib_seq) for each unique id_num. id_nums in the table have differing maximum attrib_seq values depending on the number of records for that id_num. I need the newly inserted columns to have the next highest seq_num value for each id_num. The code I have now works if only one record is inserted for a particular ID. However, if there are multiples records to insert for that ID it maintains the same value and the insert crashes. Below is the select portion of my insert. Any assistance is much appreciated.

    SELECT w.id_num,

    ISNULL((

    SELECT MAX(a.ATTRIB_SEQ)

    FROM dbo.ATTRIBUTE_TRANS a

    WHERE w.ID_NUM = a.ID_NUM

    GROUP BY a.ID_NUM

    )+1, 1) AS MAX_SEQ_NUM

    ,attribute_cde,

    'ADMIN',

    'attribute_insert',

    CURRENT_TIMESTAMP

    FROM WS_Table w

  • Please read the first article in my signature about posting these types of questions to the forum. I have added the tables and some sample data for you and using the window function ROW_NUMBER() to solve the issue. Let me know if this works for you:drop table ATTRIBUTE_TRANS;

    drop table WS_Table;

    go

    create table ATTRIBUTE_TRANS (

    ID_NUM int

    ,Attrib_seqint)

    create table WS_Table (

    id_num int

    ,attribute_cde int

    );

    insert ATTRIBUTE_TRANS

    values (1,2)

    ,(2,1);

    insert WS_Table

    values (1,1)

    , (2,1)

    , (1,2)

    , (3,1);

    SELECT w.id_num,

    ISNULL((SELECT MAX(a.ATTRIB_SEQ)

    FROM dbo.ATTRIBUTE_TRANS a

    WHERE w.ID_NUM = a.ID_NUM

    GROUP BY a.ID_NUM

    )+ROW_NUMBER() over (partition by w.id_num order by w.id_num), 1) AS MAX_SEQ_NUM

    ,attribute_cde

    ,'ADMIN'

    ,'attribute_insert'

    ,CURRENT_TIMESTAMP

    FROM WS_Table w

    EDIT: I forgot to add partition by in ROW_NUMBER



    Microsoft Certified Master - SQL Server 2008
    Follow me on twitter: @keith_tate

    Forum Etiquette: How to post data/code on a forum to get the best help[/url]

  • Thanks much for your solution, much appreciated.

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

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