Click here to monitor SSC
SQLServerCentral is supported by Red Gate Software Ltd.
 
Log in  ::  Register  ::  Not logged in
 
 
 
        
Home       Members    Calendar    Who's On


Add to briefcase

How can I set identity_insert on a tablename passed to an sproc Expand / Collapse
Author
Message
Posted Wednesday, December 22, 2010 3:23 PM
Grasshopper

GrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopper

Group: General Forum Members
Last Login: Thursday, October 11, 2012 4:09 PM
Points: 12, Visits: 36
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_ID Integer 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.
Post #1038529
Posted Wednesday, December 22, 2010 4:33 PM


SSChampion

SSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampion

Group: General Forum Members
Last Login: Today @ 3:16 AM
Points: 12,876, Visits: 31,782
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

--There is no spoon, and there's no default ORDER BY in sql server either.
Actually, Common Sense is so rare, it should be considered a Superpower. --my son
Post #1038554
Posted Wednesday, December 22, 2010 5:01 PM


SSChampion

SSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampion

Group: General Forum Members
Last Login: Today @ 3:16 AM
Points: 12,876, Visits: 31,782
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

--There is no spoon, and there's no default ORDER BY in sql server either.
Actually, Common Sense is so rare, it should be considered a Superpower. --my son
Post #1038560
Posted Wednesday, December 22, 2010 10:17 PM
SSCrazy

SSCrazySSCrazySSCrazySSCrazySSCrazySSCrazySSCrazySSCrazy

Group: General Forum Members
Last Login: Monday, June 16, 2014 9:38 AM
Points: 2,163, Visits: 2,189
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.
Post #1038596
Posted Monday, December 27, 2010 10:26 AM
Grasshopper

GrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopper

Group: General Forum Members
Last Login: Thursday, October 11, 2012 4:09 PM
Points: 12, Visits: 36
Thank you - all great answers. I really appreciate the time you put into helping me.
Post #1039496
« Prev Topic | Next Topic »

Add to briefcase

Permissions Expand / Collapse