FIX: CREATE for Existing Object with IDENTITY Column Causes Duplicate IDENTITY Values (290915)



The information in this article applies to:

  • Microsoft SQL Server 2000 (all editions)
  • Microsoft SQL Server 7.0

This article was previously published under Q290915
BUG #: 54428 (SQLBUG_70)
BUG #: 201136 (SHILOH_bugs)

SYMPTOMS

When a CREATE statement fails due to the object already existing, and one of the columns has the IDENTITY property, duplicate IDENTITY values may result. If there is a unique index or primary key on the table, subsequent inserts will fail with a "duplicate key" message.

CAUSE

The IDENTITY value is incorrectly set when a CREATE statement fails due to the object already existing.

RESOLUTION

SQL Server 2000

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

290211 INF: How to Obtain the Latest SQL Server 2000 Service Pack

SQL Server 7.0

To resolve this problem, obtain the latest service pack for 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, you can do the following:
  • Include IF NOT EXISTS before any CREATE statement.
  • Run the DBCC CHECKIDENT command after a failed CREATE statement.

STATUS

Microsoft has confirmed that this is a problem in the Microsoft products that are listed at the beginning of this article.

SQL Server 2000

This problem was first corrected in SQL Server 2000 Service Pack 1.

SQL Server 7.0

This problem was first corrected in SQL Server 7.0 Service Pack 1.

MORE INFORMATION

To reproduce the problem, run the following query multiple times:
CREATE TABLE Table1 
(IdentityColumn integer IDENTITY CONSTRAINT PK1 PRIMARY KEY NONCLUSTERED, 
 ID integer)
go
CREATE CLUSTERED INDEX Index1 ON Table1(ID,IdentityColumn)
go
INSERT INTO Table1 (ID) VALUES (100)
SELECT @@IDENTITY as "@@IDENTITY 1"
INSERT INTO Table1 (ID) VALUES (200)
SELECT @@IDENTITY as "@@IDENTITY 2"
go
				
The first run succeeds, creates the table and index, and inserts the value. In the second run, the table and index creation fail as expected. But the insert also fails with the following message:
Server: Msg 2627, Level 14, State 1, Line 1
Violation of PRIMARY KEY constraint 'PK1'. Cannot insert duplicate key in object 'Table1'. The statement has been terminated.
The IDENTITY property is reissuing its last value instead of the next available one.

Modification Type:MajorLast Reviewed:10/31/2003
Keywords:kbBug kbfix kbSQLServ2000sp1fix KB290915