Please start any new threads on our new site at https://forums.sqlteam.com. We've got lots of great SQL Server experts to answer whatever question you can come up with.

 All Forums
 SQL Server 2005 Forums
 Transact-SQL (2005)
 set identity_insert on

Author  Topic 

Zifter
Yak Posting Veteran

51 Posts

Posted - 2013-02-19 : 03:38:56
I have to work with an old 2005 database, where there are no foreign key constraints specified (I know).
Now I'm trying to copy some data from one SQL server (production) to another (test) with the following code

declare @ServerFrom as varchar(10)
declare @ServerTo as varchar(10)
declare @TableName as varchar(50)
declare @Fields as varchar(500)
declare @SqlStatement as varchar(max)

set @ServerFrom = 'ServerA';
set @ServerTo = 'ServerB';
set @TableName = 'MyDataBase.dbo.MyTable';
set @Fields = ' Field1, Field2, Field3 '

set @SqlStatement = 'delete from ' + @ServerTo + '.' + @TableName
exec(@SqlStatement);

set @SqlStatement = 'set identity_insert ' + @TableName + ' on'
exec(@SqlStatement);

set @SqlStatement = 'insert into ' + @ServerTo + '.' + @TableName +
'(' + @Fields + ') ' +
'select ' + @Fields + ' from ' + @ServerFrom + '.' + @TableName
exec(@SqlStatement);

set @SqlStatement = 'set identity_insert ' + @TableName + ' off'
exec(@SqlStatement);


But when I run this, I get the following message


Msg 544, Level 16, State 1, Line 1
Cannot insert explicit value for identity column in table 'MyTable' when IDENTITY_INSERT is set to OFF.

Although I used the statement "set identity_insert MyTable on".
What am I missing here?

visakh16
Very Important crosS Applying yaK Herder

52326 Posts

Posted - 2013-02-19 : 04:17:42
there are not in a batch. it should be inside single statement

...
set @SqlStatement = 'delete from ' + @ServerTo + '.' + @TableName +';set identity_insert ' + @TableName + ' on;' + 'insert into ' + @ServerTo + '.' + @TableName +
'(' + @Fields + ') ' +
'select ' + @Fields + ' from ' + @ServerFrom + '.' + @TableName + ';set identity_insert ' + @TableName + ' off;'
exec(@SqlStatement);



------------------------------------------------------------------------------------------------------
SQL Server MVP
http://visakhm.blogspot.com/

Go to Top of Page

Zifter
Yak Posting Veteran

51 Posts

Posted - 2013-02-19 : 04:44:39
That makes sense. Should have tried it.

Thanks visakh! You're the man.
Go to Top of Page

visakh16
Very Important crosS Applying yaK Herder

52326 Posts

Posted - 2013-02-19 : 05:12:35
welcome

------------------------------------------------------------------------------------------------------
SQL Server MVP
http://visakhm.blogspot.com/

Go to Top of Page
   

- Advertisement -