Click here to Skip to main content
15,881,281 members
Articles / Programming Languages / SQL

Difference between @@IDENTITY, SCOPE_IDENTITY, IDENT_CURRENT

Rate me:
Please Sign up or sign in to vote.
4.64/5 (44 votes)
22 Aug 2010CPOL1 min read 281.5K   46   17
Difference between SQL @@IDENTITY, SCOPE_IDENTITY, IDENT_CURRENT functions

Introduction

In most of our application scenario, we need to get latest inserted row information through SQL query. And for that, we have multiple options like:

  • @@IDENTITY
  • SCOPE_IDENTITY
  • IDENT_CURRENT

All three functions return last-generated identity values. However, the scope and session on which last is defined in each of these functions differ.

Compare

@@IDENTITY

It returns the last identity value generated for any table in the current session, across all scopes.

Let me explain this... suppose we create an insert trigger on table which inserts a row in another table with generate an identity column, then @@IDENTITY returns that identity record which is created by trigger.

SCOPE_IDENTITY

It returns the last identity value generated for any table in the current session and the current scope.

Let me explain this... suppose we create an insert trigger on table which inserts a row in another table with generate an identity column, then SCOPE_IDENTITY result is not affected but if a trigger or a user defined function is affected on the same table that produced the value returns that identity record then SCOPE_IDENTITY returns that identity record which is created by trigger or a user defined function.

IDENT_CURRENT

It returns the last identity value generated for a specific table in any session and any scope.

In other words, we can say it is not affected by scope and session, it only depends on a particular table and returns that table related identity value which is generated in any session or scope.

SQL Query

I am explaining the above process with the help of some sample query, hope it helps:

SQL
CREATE TABLE Parent(id int IDENTITY);

CREATE TABLE Child(id int IDENTITY(100,1));

GO

CREATE TRIGGER Parentins ON Parent FOR INSERT

AS

BEGIN

   INSERT Child DEFAULT VALUES

END;

GO

--End of trigger definition

SELECT id FROM Parent;
--id is empty.

SELECT id FROM Child;
--ID is empty. 

--Do the following in Session 1
INSERT Parent DEFAULT VALUES;
SELECT @@IDENTITY;
/*Returns the value 100. This was inserted by the trigger.*/

SELECT SCOPE_IDENTITY();
/* Returns the value 1. This was inserted by the
INSERT statement two statements before this query.*/ 

SELECT IDENT_CURRENT('Child');

/* Returns value inserted into Child, that is in the trigger.*/

SELECT IDENT_CURRENT('Parent');

/* Returns value inserted into Parent. 
This was the INSERT statement four statements before this query.*/ 

-- Do the following in Session 2.

SELECT @@IDENTITY;

/* Returns NULL because there has been no INSERT action
up to this point in this session.*/ 

SELECT SCOPE_IDENTITY();

/* Returns NULL because there has been no INSERT action
up to this point in this scope in this session.*/

SELECT IDENT_CURRENT('Child');

/* Returns the last value inserted into Child.*/

History

  • 22nd August, 2010: Initial post

License

This article, along with any associated source code and files, is licensed under The Code Project Open License (CPOL)


Written By
Software Developer (Senior)
India India
Hi, I am Samrat Banerjee from India.
I am a Software Engineer working in .net platform.
I love to explore new technologies.

Comments and Discussions

 
QuestionComments Pin
bikah chanda mohanta27-Apr-17 4:19
bikah chanda mohanta27-Apr-17 4:19 
Answer@@IDENTITY, SCOPE_IDENTITY, IDENT_CURRENT Pin
cauvin_stephane@yahoo.fr5-Nov-16 5:02
cauvin_stephane@yahoo.fr5-Nov-16 5:02 
GeneralMy vote of 5 Pin
neetesh12319-Oct-15 1:49
neetesh12319-Oct-15 1:49 
QuestionYour commnet iw wrong Pin
redc dccdc4-Oct-15 0:39
redc dccdc4-Oct-15 0:39 
QuestionGood Article Pin
Member 23341727-Oct-14 19:49
Member 23341727-Oct-14 19:49 
GeneralGood Artical Pin
ramprasad addanki7-Jan-14 17:52
ramprasad addanki7-Jan-14 17:52 
QuestionGood explanation Pin
rohit kakria18-Mar-12 21:14
rohit kakria18-Mar-12 21:14 
GeneralMy vote of 3 Pin
JayantiChauhan15-Mar-12 2:25
JayantiChauhan15-Mar-12 2:25 
GeneralMy vote of 1 Pin
pinaldave24-Aug-10 11:06
pinaldave24-Aug-10 11:06 
GeneralMy vote of 3 Pin
Bishoy Demian23-Aug-10 23:10
Bishoy Demian23-Aug-10 23:10 
GeneralVery Good Pin
Akhteruzzaman23-Aug-10 4:19
Akhteruzzaman23-Aug-10 4:19 
GeneralRe: Very Good Pin
Member 23341727-Oct-14 19:41
Member 23341727-Oct-14 19:41 
GeneralMy vote of 5 Pin
linuxjr23-Aug-10 2:49
professionallinuxjr23-Aug-10 2:49 
GeneralMy vote of 5 Pin
pzokarkar22-Aug-10 22:30
pzokarkar22-Aug-10 22:30 
GeneralMy vote of 5 Pin
Rahul Khadikar22-Aug-10 18:58
Rahul Khadikar22-Aug-10 18:58 
GeneralMore of a blog post Pin
Not Active21-Aug-10 12:03
mentorNot Active21-Aug-10 12:03 
GeneralRe: More of a blog post Pin
kornakar22-Aug-10 22:12
kornakar22-Aug-10 22:12 

General General    News News    Suggestion Suggestion    Question Question    Bug Bug    Answer Answer    Joke Joke    Praise Praise    Rant Rant    Admin Admin   

Use Ctrl+Left/Right to switch messages, Ctrl+Up/Down to switch threads, Ctrl+Shift+Left/Right to switch pages.