Click here to Skip to main content
Click here to Skip to main content

How to remove duplicate rows in SQL Server 2005 when no key is present

By , 20 Dec 2012
Rate this:
Please Sign up or sign in to vote.
An easy way to remove duplicate rows from a table in SQL Server 2005 is to use undocumented feature called %%lockres%%. This pseudo column shows the physical location of a row.
 
Note that this feature is undocumented and unsupported so use at your own risk!
 
A simple test-case. Create a test table:
CREATE TABLE TestTable (
   Column1 varchar(1),
   Column2 int
)
Add some rows with few duplicates:
INSERT INTO TestTable VALUES ('A', 1);
INSERT INTO TestTable VALUES ('A', 1); -- duplicate
INSERT INTO TestTable VALUES ('A', 2);
INSERT INTO TestTable VALUES ('B', 1);
INSERT INTO TestTable VALUES ('B', 2);
INSERT INTO TestTable VALUES ('B', 2); -- duplicate
INSERT INTO TestTable VALUES ('C', 2)
You can select the data to see that all seven rows are present:
SELECT *
FROM   TestTable a
ORDER BY a.Column1, a.Column2
Now let's delete the two duplicates using the %%lockres%%:
DELETE
FROM  TestTable
WHERE TestTable.%%lockres%%
      NOT IN (SELECT MIN(b.%%lockres%%)
              FROM   TestTable b
              GROUP BY b.column1, b.Column2)
And if you run the query again, you'll see that only five rows remain and duplicates have been deleted.
SELECT *
FROM   TestTable a
ORDER BY a.Column1, a.Column2
 
For more information about %%physloc%%, corresponding SQL Server 2008 pseudo column, see: Physical location of a row in SQL Server[^].
 
For SQL Server 2008 equivalent, see: How to remove duplicate rows in SQL Server 2008 when no key is present[^].

License

This article, along with any associated source code and files, is licensed under The Code Project Open License (CPOL)

About the Author

Mika Wendelius
Architect
Finland Finland
I've been a programmer since mid 80's using languages like assembler, C/C++, PL/I (mainframe environment), pascal, VB (I know, I know, no comments please) and C# and utilizing different techniques and tools.
 
However I'm specialized in databases and database modeling. Mostly I have used products like Oracle (from version 6), SQL Server (from version 4.2), DB2 and Solid Server (nowadays an IBM product).
 
For the past 10+ years my main concerns have been dealing with different business processes and how to create software to implement and improve them. At my spare time (what ever that actually means) I'm also teaching and consulting on different areas of database management, development and database oriented software design.

Comments and Discussions

 
GeneralMy vote of 5 Pinprofessionalarchana naik6-Sep-13 20:27 
GeneralRe: My vote of 5 PinmvpMika Wendelius16-Sep-13 2:53 
GeneralReason for my vote of 5 Hats off to u Pinmemberims.sanjay28-Feb-11 18:56 
GeneralRe: Thanks PinmvpMika Wendelius3-Aug-11 8:43 
GeneralReason for my vote of 5 Excellent solution! Btw, Alternate i... PinmemberDrABELL22-Feb-11 16:16 
GeneralRe: Thank you. Yes, the alternate is very good. PinmvpMika Wendelius3-Aug-11 8:43 

General General    News News    Suggestion Suggestion    Question Question    Bug Bug    Answer Answer    Joke Joke    Rant Rant    Admin Admin   

Use Ctrl+Left/Right to switch messages, Ctrl+Up/Down to switch threads, Ctrl+Shift+Left/Right to switch pages.

| Advertise | Privacy | Mobile
Web03 | 2.8.140415.2 | Last Updated 20 Dec 2012
Article Copyright 2011 by Mika Wendelius
Everything else Copyright © CodeProject, 1999-2014
Terms of Use
Layout: fixed | fluid