I know that I easily can remove duplicates based upon one field’s records, and that I can do so with respect to more than one field at one time. However, I want to remove duplicates if, for example, A1=A2 and B1=B2. In that case, I want record 1 or 2 removed. I attached a spreadsheet as an example. In the example, the duplicates would be records 2 and 4, so I want one those records removed. I think that I could do this through a couple of queries, but I’m looking for something easier. Thanks!
![]() |
Patch reliability is unclear. Unless you have an immediate, pressing need to install a specific patch, don't do it. |
SIGN IN | Not a member? | REGISTER | PLUS MEMBERSHIP |
-
Remove duplicates based on two fields
Home » Forums » AskWoody support » Productivity software by function » MS Excel and spreadsheet help » Remove duplicates based on two fields
- This topic has 11 replies, 4 voices, and was last updated 13 years, 1 month ago.
Viewing 5 reply threadsAuthorReplies-
RetiredGeek
AskWoody_MVPApril 24, 2012 at 12:26 pm #1330147Jimmy,
This code should solve your problem.
Code:Option Explicit Sub RemoveDups() Dim lCurRow As Long Dim lTestRowOffset As Long lCurRow = 2 Do lTestRowOffset = 1 Do If Cells(lCurRow, 1).Value = Cells(lCurRow + lTestRowOffset, 1).Value And _ Cells(lCurRow, 2).Value = Cells(lCurRow + lTestRowOffset, 2).Value Then Rows(lCurRow + lTestRowOffset).EntireRow.Delete Else lTestRowOffset = lTestRowOffset + 1 End If Loop Until Cells(lCurRow + lTestRowOffset, 1).Value = "" lCurRow = lCurRow + 1 Loop Until Cells(lCurRow, 1).Value = "" End Sub
Please note that I solved the problem as indicated. If the data had been sorted first the code could be a little more efficient but as it stands you have to loop through the entire data set for each itteration to make sure you have all the duplicates. Of course if your dataset {table} isn’t too big this isn’t a real problem. :cheers:
Test Data
30689-TestData
Results
30690-Results -
WSJimmy-W
AskWoody LoungerApril 24, 2012 at 1:29 pm #1330148Thanks! If I may impose with a couple of questions, can I edit the code if the two fields are not contiguous, e.g., A2 and C2? Would it then be 2TestRowOffset? I also wonder about date/time granularity. Two times may be formatted to appear as 13:10, but really may be 13:10:45 and 13:10:55, etc. Does the code use the formatted time or the actual numeric time? (My worksheet is sorted by date/time, descending order.)
-
RetiredGeek
AskWoody_MVPApril 24, 2012 at 7:54 pm #1330181Jimmy,
1. Can I edit the code if the two fields are not contiguous, e.g., A2 and C2? Yes just change the Column Numbers, they are the hard coded numbers. e.g. A=1 B=2 C=3 thus A2 & C2 would be
Code:If Cells(lCurRow, 1).Value = Cells(lCurRow + lTestRowOffset, 1).Value And _ Cells(lCurRow, 3).Value = Cells(lCurRow + lTestRowOffset, 3).Value Then
2. Does the code use the formatted time or the actual numeric time? Actual Time
Although the code could be modified to use formatted time.Code:If Format(Cells(lCurRow, 1).Value, "hh:mm") = _ Format(Cells(lCurRow + lTestRowOffset, 1).Value, "hh:mm") And _ Cells(lCurRow, 2).Value = Cells(lCurRow + lTestRowOffset, 2).Value Then
:cheers:
-
WSRoger Govier
AskWoody Lounger
-
-
RetiredGeek
AskWoody_MVPApril 26, 2012 at 10:55 am #1330445Roger,
Nice! However the VBA is more robust since it will work if the records are sorted or not. I tried your solution on my test data and it didn’t get the right answer. Then I remembered the OP has said his data was sorted by date/time decending, my test data was not. Upon sorting your solution worked perfectly and is an interesting approach to the problem.
I notice you’re a fairly new poster here so let me take this opportunity to welcome you to the Lounge as a poster. It’s always nice to have more talent, especially MVPs, to add new perspectives to the Lounge’s talent base. :cheers:
-
WSRoger Govier
AskWoody LoungerApril 26, 2012 at 12:44 pm #1330465Hi
Many thanks for the welcome.However, I fear you are incorrect in your assertion regarding sorting.
The formula solution will work with either sorted or unsorted data, as the attached workbook shows. I added some more data to jumble the order up a bit.The formula in D2
=COUNTIF($C$2:C2,C2)>1
which becomes
=COUNTIF($C$2:C14,C14)>1
by the time it gets to D14
is not concerned with any order, or referencing the row above, it is doing a Countif on an ever expanding range to see if there is more than one occurrence of the concatenated value.
-
-
RetiredGeek
AskWoody_MVPApril 26, 2012 at 1:03 pm #1330469Roger,
I’m still getting the same results. :confused:
Here’s my test workbook with both your formula and my macro, maybe you can see what I am doing wrong. :cheers: -
WSRoger Govier
AskWoody Lounger -
WSSimon Bardby
AskWoody LoungerApril 27, 2012 at 5:53 am #1330568If you’re using Excel 2007 or greater you can use the remove duplicates function once you’ve created a key field through concatenation (so the count formula is unecessary).
FWIW it’s not necessary to delimit the fields (in your concatenated key field) as this is a reference field only, ie
In C2 enter
=A2&B2note that it can easily be extended to cover as many fields as necessary (and they don’t need to be contiguous)
and the count field should cover the entire column so that the data doesn’t have to be sorted
In D2 enter
=COUNTIF(C:C,C2) -
WSRoger Govier
AskWoody LoungerApril 27, 2012 at 11:40 am #1330579Hi Simon
You are quite right that there is a remove duplicate function in later versions, I was trying to give a generic solution.
With this particular set of data you are correct, a separator is not required in the concatenation.
However, I do it as a matter of course with all concatenations, because there are occasions when you can get tripped up with different numbers of characters in the concatenated fields.On the matter of the Countif function, however, you are totally wrong.
Your formula will count the number of occurrence in the whole data set, and that would not provide a list of uniques.
You would not be able to select the rows you wanted to delete, as it would also contain the first occurrence of the value.The formula I proposed, does not need to be sorted.
-
-
-
-
RetiredGeek
AskWoody_MVPApril 28, 2012 at 1:58 pm #1330682Just to keep you all updated Roger & I had taken our discussion offline to try to resolve why we were getting different results.
It turns out it was due to my final version of code checking the time in HH:MM format vs his solution checking in HH:MM:SS format. Roger offered the following to make his do the same thing.[noparse]=TEXT(A2,”hh:mm”)&”|”&B2[/noparse]
I’d like to take this opportunity to thank Roger for hanging with me through this and discovering the problem, and of course for his elegant solution.:clapping:
Thanks to him we all now have a new technique to add to our Excel toolbox. :cheers:
Viewing 5 reply threads -

Plus Membership
Donations from Plus members keep this site going. You can identify the people who support AskWoody by the Plus badge on their avatars.
AskWoody Plus members not only get access to all of the contents of this site -- including Susan Bradley's frequently updated Patch Watch listing -- they also receive weekly AskWoody Plus Newsletters (formerly Windows Secrets Newsletter) and AskWoody Plus Alerts, emails when there are important breaking developments.
Get Plus!
Welcome to our unique respite from the madness.
It's easy to post questions about Windows 11, Windows 10, Win8.1, Win7, Surface, Office, or browse through our Forums. Post anonymously or register for greater privileges. Keep it civil, please: Decorous Lounge rules strictly enforced. Questions? Contact Customer Support.
Search Newsletters
Search Forums
View the Forum
Search for Topics
Recent Topics
-
Windows 11 Insider Preview build 26200.5641 released to DEV
by
joep517
1 hour, 13 minutes ago -
Windows 11 Insider Preview build 26120.4250 (24H2) released to BETA
by
joep517
1 hour, 14 minutes ago -
Install Office 365 Outlook classic on new Win11 machine
by
WSrcull999
1 hour, 12 minutes ago -
win 10 to win 11 with cpu/mb replacement
by
aquatarkus
2 hours, 3 minutes ago -
re-install Windows Security
by
CWBillow
4 hours, 29 minutes ago -
WWDC 2025 Recap: All of Apple’s NEW Features in 10 Minutes!
by
Alex5723
8 hours, 10 minutes ago -
macOS Tahoe 26
by
Alex5723
2 hours, 23 minutes ago -
Migrating from win10 to win11, instructions coming?
by
astro46
9 hours, 22 minutes ago -
Device Eligibility for Apple 2026 Operating Systems due this Fall
by
PKCano
8 hours, 57 minutes ago -
Recommended watching : Mountainhead movie
by
Alex5723
21 hours, 42 minutes ago -
End of support for Windows 10
by
Old enough to know better
7 hours, 4 minutes ago -
What goes on inside an LLM
by
Michael Covington
6 hours, 8 minutes ago -
The risk of remote access
by
Susan Bradley
46 minutes ago -
The cruelest month for many Office users
by
Peter Deegan
18 hours, 21 minutes ago -
Tracking protection and trade-offs in Edge
by
Mary Branscombe
23 hours, 56 minutes ago -
Supreme Court grants DOGE access to confidential Social Security records
by
Alex5723
1 day, 6 hours ago -
EaseUS Partition Master free 19.6
by
Alex5723
7 hours, 11 minutes ago -
Microsoft : Edge is better than Chrome
by
Alex5723
1 day, 19 hours ago -
The EU launched DNS4EU
by
Alex5723
2 days, 8 hours ago -
Cell Phone vs. Traditional Touchtone Phone over POTS
by
280park
1 day, 22 hours ago -
Lost access to all my networked drives (shares) listed in My Computer
by
lwerman
2 days, 13 hours ago -
Set default size for pasted photo to word
by
Cyn
2 days, 19 hours ago -
Dedoimedo tries 24H2…
by
Cybertooth
2 days, 8 hours ago -
Windows 11 Insider Preview build 27871 released to Canary
by
joep517
3 days, 18 hours ago -
Windows 11 ad from Campaign Manager in Windows 10
by
Jim McKenna
1 day, 11 hours ago -
Small desktops
by
Susan Bradley
12 hours, 29 minutes ago -
Totally disable Bitlocker
by
CWBillow
2 days, 12 hours ago -
Phishers extract Millions from HMRC accounts..
by
Microfix
3 days, 16 hours ago -
Windows 10 22H2 Update today (5 June) says up-to-date but last was 2025-04
by
Alan_uk
4 days, 22 hours ago -
Thoughts on Malwarebytes Scam Guard for Mobile?
by
opti1
2 days, 17 hours ago
Recent blog posts
Key Links
Want to Advertise in the free newsletter? How about a gift subscription in honor of a birthday? Send an email to sb@askwoody.com to ask how.
Mastodon profile for DefConPatch
Mastodon profile for AskWoody
Home • About • FAQ • Posts & Privacy • Forums • My Account
Register • Free Newsletter • Plus Membership • Gift Certificates • MS-DEFCON Alerts
Copyright ©2004-2025 by AskWoody Tech LLC. All Rights Reserved.