Get identity value of all rows inserted

  • I can use Scope_Identity() to get the last identity value inserted into an identity column. But how can i get identity values of all rows which are inserted in a insert statement?

    Example

    insert into DestinationTbl select * from SourceTbl where [col1]='xyz'

    Above statement may insert more than one rows into a table. So i want identity value of all the rows which are inserted. How it can be done?

  • Use the OUTPUT clause. There's much more that it can do (like inserting into another table) so check it out in "Books Online".

    insert into DestinationTbl

    OUTPUT INSERTED.YourIdentityColumn

    select * from SourceTbl where [col1]='xyz'

    ;

    --Jeff Moden


    RBAR is pronounced "ree-bar" and is a "Modenism" for Row-By-Agonizing-Row.
    First step towards the paradigm shift of writing Set Based code:
    ________Stop thinking about what you want to do to a ROW... think, instead, of what you want to do to a COLUMN.

    Change is inevitable... Change for the better is not.


    Helpful Links:
    How to post code problems
    How to Post Performance Problems
    Create a Tally Function (fnTally)

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

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