Use SCOPE_IDENTITY()–SQLNewBlogger

Another post for me that is simple and hopefully serves as an example for people trying to get blogging as #SQLNewBloggers.

I ran across a question on Facebook, of all places, the other day. Someone had asked a friend how to return a value from a procedure and assign it to a variable. My friend answered, but in the discussion, I noticed the poster was looking to return @@IDENTITY to the calling procedure as the value of the row that was just inserted.

Don’t do that. At least not without understanding the potential issues.

It’s been years since I’ve seen @@IDENTITY in use, and for a number of years before that, this was an easy “weed out” question in interviews.

If you look at the documentation for @@IDENTITY, the documentation notes that SCOPE_IDENTITY() and @@IDENTITY both return the last identity value inserted in the table, but @@IDENTITY is not limited in scope to the current session.  This means that when concurrent inserts occur, you could receive the identity value of another session. Depending on how you use this value, that may or may not be an issue.

How does this work? Let’s create a simple table with an identity. I also create a logging table and a trigger that will add a message to my logging table when I add a row to the first table.

CREATE TABLE newtable
    (
      id INT IDENTITY(1 ,1)
    , mychar VARCHAR(20)
    );
GO
CREATE TABLE Logger
 (logid INT IDENTITY(56,1)
 , logdate DATETIME
 , msg VARCHAR(2000)
 );
GO
CREATE TRIGGER newtable_logger ON dbo.newtable FOR INSERT
as
  INSERT INTO logger VALUES (GETDATE(), 'New value inserted into newtable.')
RETURN
;
go

If I run this, what do I expect to be returned?

INSERT INTO dbo.newtable
        ( mychar )
VALUES  ( 'First row'  -- mychar - varchar(20)
          )

SELECT @@IDENTITY



However I get this. A 56 in my result set for @@identity.

2015-09-22 17_32_20-Cortana

Why?

The reason is that the last identity value was 56, from the logging table. The order of operations is

  • insert value into newtable
  • @@identity set to 1
  • trigger fires
  • insert into logger
  • @@identity set to 56

That’s often not what we want when capturing an identity value. What’s worse, this behavior can exist, but not manifest itself until someone changes a trigger later.

If I change this SCOPE_IDENTITY(), I get a different result.

2015-09-22 17_38_26-Start

This is because the SCOPE_IDENTITY() function takes the scope into account and doesn’t get reset by the trigger code.

SQLNewBlogger

This took some time to write. Mostly because I had to setup the demo, test things, and then get the explanation straight in my head. It took me 15-20 minutes, including lookup time in BOL, but if you are new to writing, this might take a bit longer. You’d also want someone to review your explanation since this can be tricky to explain.

Reference

  • @@IDENTITY
  • SCOPE_IDENTITY()

About way0utwest

Editor, SQLServerCentral
This entry was posted in Blog and tagged , , . Bookmark the permalink.

3 Responses to Use SCOPE_IDENTITY()–SQLNewBlogger

  1. Nic says:

    I’m a big fan of using output to return this kind of information. It may involve a little more coding, but it’s so much more useful (especially if you want to return more than just that inserted value)

  2. Reblogged this on treasure4developer and commented:
    Very good example which shows difference between @@IDENTITY and SCOPE_IDENTITY()

  3. M McDonald says:

    What about using the “inserted” information

    INSERT INTO dbo.newtable ( mychar )
    OUTPUT INSERTED.id
    VALUES (‘First row’)

Comments are closed.