PRB: Guarantee @@IDENTITY Value on a Per Table BasisID: Q163446
|
SQL Server documents and treats the @@IDENTITY variable as a global
variable. The following is an excerpt from the SQL Server Books Online:
To get the last identity value, use the @@IDENTITY global variable. This variable is accurate after an insert into a table with an identity column; however, this value is reset after an insert into a table without an identity column occurs.
There is no way to implement a solid workaround without making code
changes. However, you can employ one of following two strategies:
Here you use a separate table to maintain the highest sequence number. This approach ensures that sequence numbers are assigned in sequential order, without any holds, by effectively single-threading inserts.
select @@VERSION
go
use pubs
go
set nocount on
go
print ''
print 'Create the sample tables...'
print ''
go
drop table tblAudit
go
create table tblAudit
(
iID int identity(2500,1),
strData varchar(10)
)
go
drop table tblIdentity
go
create table tblIdentity
(
iID int identity(1,1),
strData varchar(10)
)
go
print ''
print 'Create the sample procedures and triggers...'
print ''
go
create table #tblIdentity
(
iID int,
strTable varchar(30)
)
go
create trigger trgIdentity on tblIdentity for INSERT
as
insert into #tblIdentity values (@@IDENTITY, 'tblIdentity')
insert into tblAudit values ('Audit entry')
go
create trigger trgAudit on tblAudit for INSERT
as
insert into #tblIdentity values (@@IDENTITY, 'tblAudit')
go
drop procedure sp_Insert
go
create procedure sp_Insert
as
insert into tblIdentity values('Test')
print ' '
print 'Simple reliance on the @@IDENTITY after the execution would
incorrectly yield'
print 'FK references of tblIdentity would be incorrect'
print ' '
select '@@IDENTITY' = @@IDENTITY
go
drop procedure sp_GetIdentity
go
create procedure sp_GetIdentity @strTable varchar(30)
as
declare @iIdentity int
select @iIdentity = iID
from #tblIdentity
where strTable = @strTable
return @iIdentity
go
drop table #tblIdentity
go
print ''
print 'Show the process in action'
print ''
create table #tblIdentity
(
iID int,
strTable varchar(30)
)
go
exec sp_Insert
go
print ' '
print 'After execution you can get a specific table value...'
print ' '
go
declare @iIdentity int
exec @iIdentity = sp_GetIdentity 'tblIdentity'
select 'tblIdenity' = @iIdentity
exec @iIdentity = sp_GetIdentity 'tblAudit'
select 'tblAudit' = @iIdentity
drop table #tblIdentity
go
Keywords : kbcode kbusage SSrvGen
Version : WINNT:6.0,6.5,7.0
Platform : winnt
Issue type : kbprb
Last Reviewed: April 8, 1999