FIX: Incorrect Identity Values After Failed Unique Index Creation (290917)



The information in this article applies to:

  • Microsoft SQL Server 2000 (all editions)

This article was previously published under Q290917
BUG #: 351634 (SHILOH_bugs)
BUG #: 351180 (SHILOH_BUGS)

SYMPTOMS

Inserts into a table may fail due to a "duplicate key values" message when all of the following are true:
  • A table exists with a UNIQUE INDEX or PRIMARY KEY defined.
  • The table contains a column with the IDENTITY property.
  • A CREATE INDEX statement is issued for an INDEX that already exists.

CAUSE

The failed CREATE INDEX statement resets the value for the IDENTITY column to its initial seed value.

RESOLUTION

To resolve this problem, obtain the latest service pack for 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

WORKAROUND

Issue a DBCC CHECKIDENT statement after the failed index creation.

STATUS

Microsoft has confirmed that this is a problem in SQL Server 2000. This problem was first corrected in SQL Server 2000 Service Pack 1.

MORE INFORMATION

The following code reproduces the problem:
SET NOCOUNT ON
USE pubs
GO
create table IdentityRollbackTable (c1 nchar(30), id int identity (100,1))
insert IdentityRollbackTable values('NoIndex1')
insert IdentityRollbackTable values('NoIndex1')
insert IdentityRollbackTable values('NoIndex2')
insert IdentityRollbackTable values('NoIndex3')
GO
--/*'Should fail after first execution because of duplicate key.'*/ 
create unique clustered index IdentityRollbackIndex 
	on IdentityRollbackTable(c1) WITH IGNORE_DUP_KEY
GO
insert IdentityRollbackTable values('AfterFailedIndex1')
insert IdentityRollbackTable values('AfterFailedIndex2')
dbcc checkident(IdentityRollbackTable)
insert IdentityRollbackTable values('AfterCheckIdent1')
select * from IdentityRollbackTable
GO 
drop table IdentityRollbackTable
GO
				
The results show that the identity value was incorrectly reinitialized to its seed value.
Server: Msg 1505, Level 16, State 1, Line 1
CREATE UNIQUE INDEX terminated because a duplicate key was found for index ID 1. Most significant primary key is 'NoIndex1                      '.
The statement has been terminated.
Checking identity information: current identity value '101', current column value '103'.
DBCC execution completed. If DBCC printed error messages, contact your system administrator.
c1                             id          
------------------------------ ----------- 
NoIndex1                       100
NoIndex1                       101
NoIndex2                       102
NoIndex3                       103
AfterFailedIndex1              100
AfterFailedIndex2              101
AfterCheckIdent1               104
				

Modification Type:MajorLast Reviewed:11/6/2003
Keywords:kbBug kbfix kbSQLServ2000sp1fix KB290917