Please start any new threads on our new site at https://forums.sqlteam.com. We've got lots of great SQL Server experts to answer whatever question you can come up with.

 All Forums
 General SQL Server Forums
 New to SQL Server Programming
 Duplicates pointing to ID

Author  Topic 

ben_53
Yak Posting Veteran

67 Posts

Posted - 2011-09-09 : 18:47:16
Hi guys,
I have a tableA

ID col1 col2 status
1 ABC 123 NULL
2 ABC 214 NULL
3 BCA 001 NULL
4 ABC 123 NULL
5 BWE 765 NULL
6 ABC 123 NULL
7 BCA 001 NULL

I want to flag the duplicate data (col1, col2) & populate the column=status with a message referring to the ID of which is duplicate.
For example, ID=4 is duplicate of ID = 1 , ID=6 is duplicate of ID = 1 and ID 7 is duplicate of ID = 3.
status = "Duplicate of ID = (ID here) "
Expected result:



ID col1 col2 status
1 ABC 123 NULL
2 ABC 214 NULL
3 BCA 001 NULL
4 ABC 123 Duplicate of ID = 1
5 BWE 765 NULL
6 ABC 123 Duplicate of ID = 1
7 BCA 001 Duplicate of ID = 3

I can able to flag the duplicates but cant able to point then to the ID numbers. The script I used is :

WITH CTE_Duplicates1 AS
(SELECT ROW_NUMBER() OVER (PARTITION BY col1,col2
ORDER BY (SELECT 0)) RN,Status
FROM tableA
)
UPDATE CTE_Duplicates1
SET qnxtStatus = 'Duplicate of ID ='
WHERE RN<>1

Please correct. Thanks

ben_53
Yak Posting Veteran

67 Posts

Posted - 2011-09-09 : 20:07:27
Solution :

;WITH CTE_Duplicates1 AS
(
SELECT MIN(ID) OVER (PARTITION BY col1, col2) Mn,
ROW_NUMBER() OVER (PARTITION BY col1, col2 ORDER BY $/0) Rn,
*
FROM tableA
)
UPDATE CTE_Duplicates1
SET qnxtStatus = 'Duplicate of ID =' + CAST(Mn AS VARCHAR(11))
WHERE Rn > 1

Go to Top of Page
   

- Advertisement -