If you’ve been using DBCC CLONEDATABASE at all, you might have run into a cannot insert duplicate key error (or something similar) when trying to clone a database:
Database cloning for ‘YourDatabase’ has started with target as ‘COPY_YourDatabase’.
Msg 2601, Level 14, State 1, Line 1
Cannot insert duplicate key row in object ‘sys.sysschobjs’ with unique index ‘clst’. The duplicate key value is (1977058079).
If you do some searching, you’ll probably end up at this Connect item: DBCC DATABASECLONE fails on sys.sysowners.
The Connect item states that the problem exists because of user objects in model. That’s not the case here.
I’m working with a database created in SQL Server 2000…now running on SQL Server 2016. It turns out that when you create new user tables in a SQL Server 2000 database, the first objects have the IDs 1977058079, 2009058193, and 2041058307. (Yes, we actually tested this…I had a copy of SQL 2000 in a VM but Jonathan installed one and dug into it to figure out the IDs.) There were a lot of changes between SQL Server 2000 and SQL Server 2005, and that included changes to model. In the model database in SQL Server 2005 and higher, the aforementioned IDs are used for QueryNotificationErrorsQueue, EventNotificationErrorsQueue and ServiceBrokerQueue respectively…Service Broker objects. As a result, my user database – created in SQL Server 2000 – has user objects with IDs that are the same as system objects in model (and of course when the system objects like QueryNotificationErrorsQueue, EventNotificationErrorsQueue and ServiceBrokerQueue got created in my user database, they got completely different IDs).
Edit 2017-06-15: This issue is fixed in CU3 for SQL Server 2016 SP1 and CU5 for SQL Server 2014 SP2! See KB 4016238, FIX: DBCC CLONEDATABASE is unsuccesful if the source database has an object originally created in SQL Server 2000.
To determine if this is an issue for any of your user databases you can use the following queries (change user_database to the name of your DB):
/* lists tables in the user database that have an ID that matches an object in model */ SELECT m.id, m.name, c.name, c.id, m.type FROM model.sys.sysobjects m FULL OUTER JOIN user_database.sys.sysobjects c ON m.id = c.id JOIN user_database.sys.objects o ON c.id = o.object_id WHERE o.is_ms_shipped != 1 AND m.id IS NOT NULL; /* lists system objects in the user database that do *not* match the id of the same object in model (FYI only) */ SELECT m.id, m.name, c.name, c.id, m.type FROM model.sys.sysobjects m FULL OUTER JOIN user_database.sys.sysobjects c ON m.name = c.name JOIN user_database.sys.objects o ON c.id = o.object_id WHERE m.id != c.id
To workaround this, you need different IDs for the affected objects in the user database. Now, I could recreate my tables in the user database, confirm the ID isn’t used for any system object in model, and then move the data over… But I have some tables that are larger than 100GB, so it’s not an easy fix.
If you’re interested in reproducing the issue, sample code is below (thanks Jonathan). You need SQL Server 2000 installed and at least SQL Server 2005 or 2008 or 2008R2. You cannot restore the SQL 2000 backup to SQL Server 2016 directly, you must do an intermediate upgrade to 2005, 2008, or 2008R2, then go to 2016. Paul has tested upgrading a SQL Server 2005 database to a newer instance here; but for SQL Server 2000 you have to perform the intermediate upgrade.
Code to create the issue
DROP DATABASE New2000 GO CREATE DATABASE New2000 GO USE New2000 GO DECLARE @loop INT SET @loop = 0 WHILE @loop < 3 BEGIN DECLARE @table NVARCHAR(4000) SET @table = 'table_' + REPLACE(REPLACE(REPLACE(REPLACE(CONVERT(VARCHAR(30), GETDATE(), 121), ':', ''), '-', ''), ' ', ''), '.', '') DECLARE @sql NVARCHAR(4000) SET @sql = 'CREATE TABLE ' + @table+ ' (RowID INT)'; EXEC(@sql) SET @Loop = (select COUNT(*) FROM sysobjects WHERE id IN ( 1977058079, 2009058193, 2041058307) ) IF @loop = 0 BEGIN PRINT 'Dropping Table' SET @sql = 'DROP TABLE '+ @table EXEC(@sql) END WAITFOR DELAY '00:00:00.010' END /* Backup the database in SQL Server 2000 Restore in SQL Server 2016 */ DBCC CLONEDATABASE ('New2000', 'COPY_New2000'); GO
9 thoughts on “DBCC CLONEDATABASE Cannot insert duplicate key Error”
We saw this too and worked around it, but looks like it’s been fixed recently:
https://support.microsoft.com/en-us/help/4016238/fix-dbcc-clonedatabase-is-unsuccessful-if-the-source-database-has-an-o
Thanks Alex! I couldn’t read that link, but this worked: https://support.microsoft.com/en-us/help/4019916 Now to upgrade!
Erin – I have a brand new SQL 2016/SP1/CU3 install that is exhibiting this issue. User databases upgraded from SQL 2008R2 (not sure before that), so this is definitely still an issue.
Ned-
I’d recommend opening up a Connect item!
Erin
Hello, I am getting an error like:
“Database cloning for ” has started with target as ”.
Msg 2601, Level 14, State 1, Line 1
Cannot insert duplicate key row in object ‘sys.syssingleobjrefs’ with unique index ‘clst’. The duplicate key value is (6, 51, 0).”
This database was upgraded from SQL 2008R2 (not sure before that).
My server is using SQL Server 2016 Ent Edition SP2 – 13.0.5233
My DB has SQL_Latin1_General_CP1_CI_AS collation and 130 compatibility level.
Looks like the issue is back.
Msg 2601, Level 14, State 1, Line 1
Cannot insert duplicate key row in object ‘sys.sysowners’ with unique index ‘nc1’. The duplicate key value is (ASH Developer).
It’s on the Microsoft SQL Server 2016 (SP2-GDR) (KB4505220) – 13.0.5101.9 (X64) Jun 15 2019 23:15:58 Copyright (c) Microsoft Corporation Enterprise Edition (64-bit) on Windows Server 2016 Standard 10.0 (Build 14393: ) (Hypervisor)
Drop user ASH Developer from SECURITY tab of database and it should work.
there are some user objects in model database