This article will show you how to get the current identity value from a table and also some things that might act a little different than you would expect
Let's first create our two simple tables
CREATE TABLE TestOne (id INT identity,SomeDate DATETIME)
CREATE TABLE TestTwo (id INT identity,TestOneID INT,SomeDate DATETIME)
--Let's insert 4 rows into the table
INSERT TestOne VALUES(GETDATE())
INSERT TestOne VALUES(GETDATE())
INSERT TestOne VALUES(GETDATE())
INSERT TestOne VALUES(GETDATE())
Here are 6 ways to check for the current value
--1 @@IDENTITY
SELECT @@IDENTITY
--this returns 4
--2 DBCC CHECKIDENT
DBCC CHECKIDENT (TestOne, NORESEED)
after running DBCC CHECKIDENT the message returned is
Checking identity information: current identity value '4', current column value '4'.
DBCC execution completed. If DBCC printed error messages, contact your system administrator.
--3 MAX function
SELECT MAX(id)
FROM TestOne
you can also check with the MAX function but this is not recommended becuase you might get some other identity value that is not yours but from a different user
--4 TOP 1 and ORDER BY DESC
SELECT TOP 1 id
FROM TestOne
ORDER BY id DESC
--The same applies here as for the max function, this is not recommended
--5 IDENT_CURRENT
SELECT IDENT_CURRENT('TestOne')
--IDENT_CURRENT is another way to check
--6 SCOPE_IDENTITY
SELECT SCOPE_IDENTITY()
--This one is very similar to @@IDENTITY with one BIG difference (shown later)
--Let's add a trigger to the TestOne table
CREATE TRIGGER trTestOne ON [dbo].[TestOne]
FOR INSERT
AS
DECLARE @CreditUserID INT
SELECT @CreditUserID = (SELECT ID FROM Inserted)
INSERT TestTwo VALUES(@CreditUserID,GETDATE())
GO
--Let's insert another row into the TestOne table
INSERT TestOne VALUES(GETDATE())
SELECT @@IDENTITY --1
SELECT @@IDENTITY,SCOPE_IDENTITY(),IDENT_CURRENT('TestOne') --1,5,5
Now why doesn't @@IDENTITY return 5 but 1?
This is because @@IDENTITY doesn't care about scope and returns the last identity value from all the statements, which in this case is from the code within the trigger trTestOne
So the bottom line is this: Always use SCOPE_IDENTITY() unless you DO need the last identity value regradless of scope (for example you need to know the identity from the table insert inside the trigger)
--Clean up this mess
DROP TABLE TestOne,TestTwo
You should have your computing license revoked for suggesting that #3 or #4 are acceptable in any way, shape, or form.
ReplyDelete