Monday, March 19, 2012

best practice retrieveing current identity value

HI all,
I have a claim table. An insert trigger, in that insert trigger I want to
retrieve the current identity value of that insert, to be used elswhere
which is best scope_identity(), ident_current(), or @.@.identity
Thanks
RobertRobert,
All three will (in theory) work, and each has it's own values for a given
situation.
I tend to use @.@.identity, though, as BoL explains, this is not limited to
the current scope, and so they would suggest using SCOPE_IDENTITY which woul
d
be more exacting.
Hope this assists,
Tony
"Robert Bravery" wrote:

> HI all,
> I have a claim table. An insert trigger, in that insert trigger I want to
> retrieve the current identity value of that insert, to be used elswhere
> which is best scope_identity(), ident_current(), or @.@.identity
> Thanks
> Robert
>
>|||Robert Bravery wrote:
> HI all,
> I have a claim table. An insert trigger, in that insert trigger I want to
> retrieve the current identity value of that insert, to be used elswhere
> which is best scope_identity(), ident_current(), or @.@.identity
> Thanks
> Robert
Did you read about the differences between those functions in Books
Online? Either may be appropriate depending on requirements.
BUT - a big but - they are all unlikely to be useful in a trigger.
That's because well-written trigger code should always assume that more
than one row may be updated in the table that invokes the trigger.
Triggers fire once per statement, NOT once per row, so usually in a
trigger if you want to retrieve the inserted IDENTITY values you do so
by referencing the virtual table called INSERTED. That table could
contain 0,1,2 or any number of rows.
The IDENTITY functions would probably only be useful in a trigger if
your trigger contained a single row INSERT to another table regardless
of how many rows were updated by the statement that prompted the
trigger. In that case you would probably use SCOPE_IDENTITY.
Hope this helps.
David Portas, SQL Server MVP
Whenever possible please post enough code to reproduce your problem.
Including CREATE TABLE and INSERT statements usually helps.
State what version of SQL Server you are using and specify the content
of any error messages.
SQL Server Books Online:
http://msdn2.microsoft.com/library/ms130214(en-US,SQL.90).aspx
--|||David,
Interesting point. Where would that leave us when using either
SCOPE_IDENTITY or @.@.Identity from a SProc? I was under the belief that the
correct identity was always returned from that thread used. Would you say
then that a trigger could be less precise than a SProc for retrieving the
correct Identity for a given inert transaction?
Any further insight would be useful,
Thanks,
Tony
"David Portas" wrote:

> Robert Bravery wrote:
> Did you read about the differences between those functions in Books
> Online? Either may be appropriate depending on requirements.
> BUT - a big but - they are all unlikely to be useful in a trigger.
> That's because well-written trigger code should always assume that more
> than one row may be updated in the table that invokes the trigger.
> Triggers fire once per statement, NOT once per row, so usually in a
> trigger if you want to retrieve the inserted IDENTITY values you do so
> by referencing the virtual table called INSERTED. That table could
> contain 0,1,2 or any number of rows.
> The IDENTITY functions would probably only be useful in a trigger if
> your trigger contained a single row INSERT to another table regardless
> of how many rows were updated by the statement that prompted the
> trigger. In that case you would probably use SCOPE_IDENTITY.
> Hope this helps.
> --
> David Portas, SQL Server MVP
> Whenever possible please post enough code to reproduce your problem.
> Including CREATE TABLE and INSERT statements usually helps.
> State what version of SQL Server you are using and specify the content
> of any error messages.
> SQL Server Books Online:
> http://msdn2.microsoft.com/library/ms130214(en-US,SQL.90).aspx
> --
>|||Tony Scott wrote:
> David,
> Interesting point. Where would that leave us when using either
> SCOPE_IDENTITY or @.@.Identity from a SProc? I was under the belief that the
> correct identity was always returned from that thread used. Would you say
> then that a trigger could be less precise than a SProc for retrieving the
> correct Identity for a given inert transaction?
> Any further insight would be useful,
> Thanks,
> Tony
>
SCOPE_IDENTITY does always have local scope but so does the INSERTED
virtual table in a trigger. In that respect a trigger is no less
precise in the way IDENTITY is retrieved - it's just that you have to
allow for multiple-row inserts. Example:
CREATE TABLE T1 (x INTEGER NOT NULL IDENTITY PRIMARY KEY, z INTEGER NOT
NULL UNIQUE)
GO
CREATE TRIGGER trg ON T1 FOR INSERT
AS
SELECT SCOPE_IDENTITY() AS [scope_identity] ;
SELECT @.@.IDENTITY AS [@.@.identity] ;
SELECT IDENT_CURRENT('T1') AS [ident_current] ;
GO
INSERT INTO T1 (z)
SELECT 1 UNION ALL
SELECT 2 ;
scope_identity
---
NULL
(1 row(s) affected)
@.@.identity
---
2
(1 row(s) affected)
ident_current
---
2
(1 row(s) affected)
The first result (NULL) is wrong because SCOPE_IDENTITY has local scope
so it doesn't see the INSERT at all.
The second is wrong because although it returns one of the IDENTITY
values there were actually two rows inserted. We can't predict the row
for which the IDENTITY will be returned - it will just be the highest
numbered IDENTITY value. This isn't good in a trigger because we can
only use this method to reference a single row and triggers should
always assume multiple rows may be updated.
The third result may be wrong if other connections also update the
table because IDENT_CURRENT is scoped to the table and not to the
session.
The reliable method uses the INSERTED table:
CREATE TRIGGER trg ON T1 FOR INSERT
AS
SELECT x FROM inserted ;
GO
If your procs insert multiple rows you also need to think about the
same issue in procs when you need the IDENTITY value. Don't assume the
values inserted will be contiguous with the value returned by
SCOPE_IDENTITY. There are at least some conditions where they may not
be.
In SQL Server 2005 you can address things slightly differently using
the OUPUT clause of the INSERT, UPDATE and DELETE statements. These
could eliminate the need for some triggers.
In SQL Server 2000 you should also be able to retrieve multiple
IDENTITY values using an alternate key of the table. There should
always be another candidate key. If you don't have such a key then you
have a significant design flaw which you should fix.
David Portas, SQL Server MVP
Whenever possible please post enough code to reproduce your problem.
Including CREATE TABLE and INSERT statements usually helps.
State what version of SQL Server you are using and specify the content
of any error messages.
SQL Server Books Online:
http://msdn2.microsoft.com/library/ms130214(en-US,SQL.90).aspx
--|||David,
Thank you for an excellent answer, very informative.
Tony
"David Portas" wrote:

> Tony Scott wrote:
> SCOPE_IDENTITY does always have local scope but so does the INSERTED
> virtual table in a trigger. In that respect a trigger is no less
> precise in the way IDENTITY is retrieved - it's just that you have to
> allow for multiple-row inserts. Example:
> CREATE TABLE T1 (x INTEGER NOT NULL IDENTITY PRIMARY KEY, z INTEGER NOT
> NULL UNIQUE)
> GO
> CREATE TRIGGER trg ON T1 FOR INSERT
> AS
> SELECT SCOPE_IDENTITY() AS [scope_identity] ;
> SELECT @.@.IDENTITY AS [@.@.identity] ;
> SELECT IDENT_CURRENT('T1') AS [ident_current] ;
> GO
> INSERT INTO T1 (z)
> SELECT 1 UNION ALL
> SELECT 2 ;
> scope_identity
> ---
> NULL
> (1 row(s) affected)
> @.@.identity
> ---
> 2
> (1 row(s) affected)
> ident_current
> ---
> 2
> (1 row(s) affected)
>
> The first result (NULL) is wrong because SCOPE_IDENTITY has local scope
> so it doesn't see the INSERT at all.
> The second is wrong because although it returns one of the IDENTITY
> values there were actually two rows inserted. We can't predict the row
> for which the IDENTITY will be returned - it will just be the highest
> numbered IDENTITY value. This isn't good in a trigger because we can
> only use this method to reference a single row and triggers should
> always assume multiple rows may be updated.
> The third result may be wrong if other connections also update the
> table because IDENT_CURRENT is scoped to the table and not to the
> session.
> The reliable method uses the INSERTED table:
> CREATE TRIGGER trg ON T1 FOR INSERT
> AS
> SELECT x FROM inserted ;
> GO
> If your procs insert multiple rows you also need to think about the
> same issue in procs when you need the IDENTITY value. Don't assume the
> values inserted will be contiguous with the value returned by
> SCOPE_IDENTITY. There are at least some conditions where they may not
> be.
> In SQL Server 2005 you can address things slightly differently using
> the OUPUT clause of the INSERT, UPDATE and DELETE statements. These
> could eliminate the need for some triggers.
> In SQL Server 2000 you should also be able to retrieve multiple
> IDENTITY values using an alternate key of the table. There should
> always be another candidate key. If you don't have such a key then you
> have a significant design flaw which you should fix.
> --
> David Portas, SQL Server MVP
> Whenever possible please post enough code to reproduce your problem.
> Including CREATE TABLE and INSERT statements usually helps.
> State what version of SQL Server you are using and specify the content
> of any error messages.
> SQL Server Books Online:
> http://msdn2.microsoft.com/library/ms130214(en-US,SQL.90).aspx
> --
>|||Hi,
Thanks for the reply David.

> Did you read about the differences between those functions in Books
> Online? Either may be appropriate depending on requirements.
Yes I did. And I also got the idea that they all might be appropiate. But no
quite understanding the exact process of a insert trigger (as you explained)
I was as to what was the more correct way

> BUT - a big but - they are all unlikely to be useful in a trigger.
> That's because well-written trigger code should always assume that more
> than one row may be updated in the table that invokes the trigger.
> Triggers fire once per statement, NOT once per row, so usually in a
> trigger if you want to retrieve the inserted IDENTITY values you do so
> by referencing the virtual table called INSERTED. That table could
> contain 0,1,2 or any number of rows.
At this point I am assumning a single row insert transaction. The table
involved is a claims table, needing a single input for each claim
as in:
INSERT INTO [RASRMIS].[dbo].[Claim]([divid], [dhid], [LayerID], [peril],
[cause], [resource], [fault], [DOL], [DREP])
VALUES(1812, 1237, 5, 1, 1, 1, 1, getdate()-1650, getdate())
Would this be considered as a single row insert, on a single statement,
single transaction
I then issued:
Select @.@.identity [@.@.Identity], SCOPE_IDENTITY() [SCOPE_IDENTITY()],
ident_current('claim') [ident_current()]
But got back all the same value.
But if I put the above statement into a trigger, I receive the dame values
from the @.@.identity and ident_current() functions. Scope_identity() returns
null. I would have thought that the insert trigger is within scope here
Hopefully I have explained correctly
Thankls
Robert|||Robert Bravery wrote:
> At this point I am assumning a single row insert transaction.
Why would you bother to assume that? It doesn't help you. It just means
the DBA will curse you one day when he needs to do some ad-hoc
maintenance... or integrate some external data... or the user needs an
enhancement to the application, or...

> The table
> involved is a claims table, needing a single input for each claim
> as in:
> INSERT INTO [RASRMIS].[dbo].[Claim]([divid], [dhid], [LayerID], [peril],
> [cause], [resource], [fault], [DOL], [DREP])
> VALUES(1812, 1237, 5, 1, 1, 1, 1, getdate()-1650, getdate())
> Would this be considered as a single row insert, on a single statement,
> single transaction
> I then issued:
> Select @.@.identity [@.@.Identity], SCOPE_IDENTITY() [SCOPE_IDENTITY()],
> ident_current('claim') [ident_current()]
> But got back all the same value.
> But if I put the above statement into a trigger, I receive the dame values
> from the @.@.identity and ident_current() functions. Scope_identity() return
s
> null. I would have thought that the insert trigger is within scope here
>
No. The trigger runs in its own scope.
The solution is:
SELECT id FROM inserted ;
"Inserted" is a virtual table only visible in triggers.
This isn't a good example because you don't usually want to return
results from triggers. The exact solution of course depends on what you
want to do with the IDENTITY value(s) after you retrieve them. For
example you can insert them to another table:
INSERT INTO other_table (id, ...)
SELECT id
FROM inserted ;
Hope this helps.
David Portas, SQL Server MVP
Whenever possible please post enough code to reproduce your problem.
Including CREATE TABLE and INSERT statements usually helps.
State what version of SQL Server you are using and specify the content
of any error messages.
SQL Server Books Online:
http://msdn2.microsoft.com/library/ms130214(en-US,SQL.90).aspx
--|||Unless you're using an INSTEAD OF INSERT trigger, then you shouldn't rely on
the value returned by @.@.IDENTITY; under no circumstances should you rely on
the value returned by IDENT_CURRENT()--at least not for what you're looking
for. There can be more than one FOR or AFTER INSERT trigger on a table, and
any one of them could affect @.@.IDENTITY. IDENT_CURRENT() changes whenever
any INSERT occurs on any connection, so it could change between the time
that you read it and the time that you're ready to use it, or even worse: it
could change during whatever modification you're trying to make. In a FOR
or AFTER trigger, the only reliable ways to retrieve the generated IDENTITY
values is to use the inserted pseudotable, or to use another candidate key.
An INSTEAD OF trigger fires instead of the action specified, so new IDENTITY
values haven't yet been generated at the time that the inserted pseudotable
is populated. You can use SCOPE_IDENTITY() if you use a cursor to process
the contents of the inserted pseudotable, but I would recommend against it.
Using cursors in triggers is like publishing uncomplimentary caricatures of
Mohammed: you're bound to get burned. In an INSTEAD OF INSERT trigger,
you're best bet is to use another candidate key to obtain the IDENTITY
values.
"Robert Bravery" <me@.u.com> wrote in message
news:u07T2i9KGHA.1424@.TK2MSFTNGP12.phx.gbl...
> HI all,
> I have a claim table. An insert trigger, in that insert trigger I want to
> retrieve the current identity value of that insert, to be used elswhere
> which is best scope_identity(), ident_current(), or @.@.identity
> Thanks
> Robert
>

No comments:

Post a Comment