Microsoft KB Archive/319699

From BetaArchive Wiki
Knowledge Base


FIX: @@IDENTITY Does Not Process a New Value When You Use INSERT EXEC

Article ID: 319699

Article Last Modified on 4/25/2002



APPLIES TO

  • Microsoft SQL Server 7.0 Standard Edition



This article was previously published under Q319699

BUG #: 101772 (SQLBUG_70)

SYMPTOMS

When you insert a value into a table by using the INSERT EXEC syntax in a stored procedure, @@IDENTITY does not reflect the new value that you are inserting; however, if you use EXEC with an explicit INSERT INTO TABLENAME VALUES () statement, @@IDENTITY reflects the new identity value.

The following example demonstrates that if you use INSERT...EXEC to insert into a table, the value that is returned for @@IDENTITY is NULL even though the statement adds a row to the table with an identity of 1:

CREATE TABLE #TEST1(COL1 INT, COL2 INT NOT NULL IDENTITY(1,1))
GO
CREATE PROC TESTPROC AS SELECT CONVERT(INT,(RAND()*100))
GO
INSERT #TEST1
  EXEC ('TESTPROC')
SELECT @@IDENTITY AS ID1
                

The preceding code sample returns NULL as if no value were inserted.

EXEC ('INSERT #TEST1 VALUES(25)')
SELECT @@IDENTITY AS ID2
                

The preceding code sample reflects the correct @@IDENTITY value.

RESOLUTION

To resolve this problem, obtain the latest service pack for Microsoft SQL Server 7.0. For additional information, click the following article number to view the article in the Microsoft Knowledge Base:

301511 INF: How to Obtain the Latest SQL Server 7.0 Service Pack


WORKAROUND

To work around this problem, use the INSERT ...VALUES syntax to insert values if you must use @@IDENTITY to get the last identity value. Otherwise, use SELECT MAX(IDENTITYCOL) FROM TABLENAME to get the correct value for the last inserted identity value if this is what you want.

STATUS

Microsoft has confirmed that this is a problem in the Microsoft products that are listed at the beginning of this article. This problem was first corrected in Microsoft SQL Server 7.0 Service Pack 4.


Keywords: kbbug kbfix kbsqlserv700presp4fix KB319699