//
you're reading...
T-SQL

T-SQL Merge Tries to Insert Duplicate Record into table with unique index.

Every get a Cannot insert duplicate key row in object when attempting to merge source and destination via a merge statement when you have specified a match on the unique key fields. More then likely this is caused by nulls in the source and destination key columns. More then likely you specified a unique index over a primary key because some of the unique keys may contain null values. Well, the merge does not do a good job of implicit NULL value comparisons and will always fail the match comparison when nulls are implicitly compared. Therefore you  must do an explicit NULL comparison. (see below)

MERGE INTO MERGE_TEST2 A
USING (SELECT * FROM MERGE_TEST1 ) B
ON (
A.SOMEID = B.SOMEID AND
(A.DESC1 = B.DESC1 OR (A.DESC1 IS NULL AND B.DESC1 IS NULL)))
WHEN MATCHED THEN UPDATE SET
A.DESC2 = B.DESC2
WHEN NOT MATCHED THEN INSERT(
SOMEID,
DESC1,
DESC2)
VALUES(
B.SOMEID,
B.DESC1,
B.DESC2);

Advertisements

About ldgaller

Accomplished Data Warehouse Architect, DBA and Software Architect with over 15 years of professional experience and demonstrated success designing and implementing solutions that improve business functionality and productivity. Highly diverse technical background with proven ability to design, develop and implement technology on an enterprise level. I approach all projects with passion, diligence, integrity, and exceptional aptitude.

Discussion

No comments yet.

Leave a Reply

Fill in your details below or click an icon to log in:

WordPress.com Logo

You are commenting using your WordPress.com account. Log Out / Change )

Twitter picture

You are commenting using your Twitter account. Log Out / Change )

Facebook photo

You are commenting using your Facebook account. Log Out / Change )

Google+ photo

You are commenting using your Google+ account. Log Out / Change )

Connecting to %s

%d bloggers like this: