Login or Sign Up to become a member!
LessThanDot Site Logo

LessThanDot

Community Wiki

Less Than Dot is a community of passionate IT professionals and enthusiasts dedicated to sharing technical knowledge, experience, and assistance. Inside you will find reference materials, interesting technical discussions, and expert tips and commentary. Once you register for an account you will have immediate access to the forums and all past articles and commentaries.

LTD Social Sitings

Lessthandot twitter Lessthandot Linkedin Lessthandot facebook Lessthandot rss

Note: Watch for social icons on posts by your favorite authors to follow their postings on these and other social sites.

Navigation

Google Ads

6 Different Ways To Get The Current Identity Value

From Wiki

Jump to: navigation, search

This tip 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

  1. CREATE TABLE TestOne (id INT identity,SomeDate DATETIME)
  2.     CREATE TABLE TestTwo (id INT identity,TestOneID INT,SomeDate DATETIME)
  3.  
  4.     --Let's insert 4 rows into the table
  5.     INSERT TestOne VALUES(GETDATE())
  6.     INSERT TestOne VALUES(GETDATE())
  7.     INSERT TestOne VALUES(GETDATE())
  8.     INSERT TestOne VALUES(GETDATE())


Here are 6 ways to check for the current value


@@IDENTITY

  1. SELECT @@IDENTITY
  2.     --this returns 4



DBCC CHECKIDENT

  1. 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.


MAX function

  1. SELECT MAX(id)
  2.     FROM TestOne

You can also check with the MAX function but this is not recommended because you might get some other identity value that is not yours but from a different user


TOP 1 and ORDER BY DESC

  1. SELECT TOP 1 id
  2.     FROM TestOne
  3.     ORDER BY id DESC

The same applies here as for the max function, this is not recommended


IDENT_CURRENT

  1. SELECT IDENT_CURRENT('TestOne')


SCOPE_IDENTITY

  1. 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

  1. CREATE TRIGGER trTestOne ON [dbo].[TestOne]
  2.     FOR INSERT
  3.     AS
  4.     DECLARE @CreditUserID INT
  5.  
  6.     SELECT @CreditUserID = (SELECT ID FROM Inserted)
  7.  
  8.     INSERT TestTwo VALUES(@CreditUserID,GETDATE())
  9.     GO


Let's insert another row into the TestOne table

  1. INSERT TestOne VALUES(GETDATE())


Now run this

  1. SELECT @@IDENTITY --1
  2.     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)

But don't let the above test convince you that SCOPE_IDENTITY() and IDENT_CURRENT('TestOne') will always return the same value. If another user adds a record to TestOne after you inserted but before you run the code for IDENT_CURRENT('TestOne'),the value will be 6 instead of 5 for IDENT_CURRENT('TestOne'). This is because it returns the last identity value on the table no matter what user added the record.

  1. --Clean up this mess
  2.     DROP TABLE TestOne,TestTwo


Contributed by: --SQLDenis 02:50, 31 May 2008 (GMT)

Part of SQL Server Programming Hacks

Section Handy tricks

173 Rating: 3.3/5 (63 votes cast)