How can I set identity_insert on a tablename passed to an sproc

  • I have the tablename in a @variable. I build the SET IDENTITY_INSERT and execute it. There's no error, but a subsequent insert fails. The code below illustrates the problem.

    CREATE TABLE IDDemo

    (pk_IDInteger IDENTITY(1,1)

    ,Textdata Varchar(100))

    SET IDENTITY_INSERT IDDemo OFF

    SET IDENTITY_INSERT IDDemo ON

    INSERT IDDemo (pk_ID, Textdata) Values (3, 'This works')

    SET IDENTITY_INSERT IDDemo OFF

    EXEC ('SET IDENTITY_INSERT IDDemo ON')

    INSERT IDDemo (pk_ID, Textdata) Values (4, 'This fails')

    Select *

    From IDDemo

    Drop Table IDDemo

    When I run it (sql2005), I get an error: Cannot insert explicit value for identity column...

    Only one row is returned.

  • Don i think your EXC command needs to do everything all together; you can separate commands with a semi colon, which is rumored to be mandatory in a future version of SQL.

    this works for example:

    CREATE TABLE IDDemo

    ( pk_ID Integer IDENTITY(1,1)

    , Textdata Varchar(100) )

    EXEC ('SET IDENTITY_INSERT IDDemo ON;INSERT IDDemo (pk_ID, Textdata) Values (4, ''This works too'');SET IDENTITY_INSERT IDDemo OFF;')

    SELECT * FROM IDDemo

    Lowell


    --help us help you! If you post a question, make sure you include a CREATE TABLE... statement and INSERT INTO... statement into that table to give the volunteers here representative data. with your description of the problem, we can provide a tested, verifiable solution to your question! asking the question the right way gets you a tested answer the fastest way possible!

  • since you said you are building a string, this is probably what you want for a demo:

    CREATE TABLE IDDemo

    ( pk_ID Integer IDENTITY(1,1)

    , Textdata Varchar(100) )

    DECLARE @sql varchar(max)

    declare @tablename varchar(30)

    SET @sql = 'SET IDENTITY_INSERT @TheDynamicTableName ON;INSERT @TheDynamicTableName (pk_ID, Textdata) Values (4, ''This works too'');SET IDENTITY_INSERT @TheDynamicTableName OFF;'

    SET @tablename = 'IDDemo'

    SET @sql = REPLACE(@sql,'@TheDynamicTableName',@tablename)

    PRINT @sql

    EXEC (@sql)

    SELECT * FROM IDDemo

    Lowell


    --help us help you! If you post a question, make sure you include a CREATE TABLE... statement and INSERT INTO... statement into that table to give the volunteers here representative data. with your description of the problem, we can provide a tested, verifiable solution to your question! asking the question the right way gets you a tested answer the fastest way possible!

  • Don Bernstein (12/22/2010)


    SET IDENTITY_INSERT IDDemo OFF

    EXEC ('SET IDENTITY_INSERT IDDemo ON')

    INSERT IDDemo (pk_ID, Textdata) Values (4, 'This fails')

    When I run it (sql2005), I get an error: Cannot insert explicit value for identity column...

    Only one row is returned.

    IDENTITY_INSERT is a session level option, and essentially anything you run with with EXEC runs in a new session. So like the other people said, and provided examples for, you would need to put anything that relies on the IDENTITY_INSERT option into the dynamic SQL, but make sure you watch out for SQL injections, since to set the IDENTITY_INSERT option requires a fair amount of privileges. Of course to be of any value your INSERT would have to by dynamic as well, since I assume that you want to insert into the table passed as a parameter.

    Another option, if the set of tables is know, is to use IF statements to turn the option on for the correct table and INSERT the record. Yes, it is more code to manage but you wouldn't have to worry about SQL injection.

  • Thank you - all great answers. I really appreciate the time you put into helping me.

Viewing 5 posts - 1 through 4 (of 4 total)

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