VBA To Determine If Duplicates Exist In Range

What This VBA Code Does
There may be instances where you need to ensure there are no duplicate values within a cell range before preceding with your macro code. The following VBA code runs a test on a given range of cells to determine if duplicate values exist.
VBA Code – Test If Duplicate Exists (test only):
OPTION #1:
This short bit of code will determine whether duplicates exist in a given cell range. It does not report the value of the duplicate that was found.
Sub TestForDuplicates()
'PURPOSE: Determine if duplicate values exist in a provided range
'SOURCE: www.TheSpreadsheetGuru.com/the-code-vault
Dim rng As Range
'Store Range to search through
Set rng = Range("A1:A3")
'Test Range for Duplicates
If Evaluate(Replace("NOT(AND((COUNTIF(@,@)=1)))", "@", rng.Address)) = True Then
MsgBox "Duplicates Found! Aborting..."
Else
MsgBox "No Duplicates Found. Continuing on..."
End If
End Sub
OPTION #2:
If you have a newer version of Excel, you can utilize the UNIQUE() function to provide a similar test.
Sub TestForDuplicates()
'PURPOSE: Determine if duplicate values exist in a provided range
'SOURCE: www.TheSpreadsheetGuru.com/the-code-vault
Dim rng As Range
Dim myArray As Variant
'Store Range to search through
Set rng = Range("A1:A3")
'Use Unique Function and store result to an Array variable
myArray = WorksheetFunction.Unique(rng)
'Test Range for Duplicates
If UBound(myArray) < rng.Count Then
MsgBox "Duplicates Found! Aborting..."
Else
MsgBox "No Duplicates Found. Continuing on..."
End If
End Sub
VBA Code – Test If Duplicate Exists (report duplicate):
If you need/want to tell the user which duplicate value was found, we can add a little more code to loop through all the cells and test against a list of the unique values found.
Sub TestForDuplicates()
'PURPOSE: Determine if duplicate values exist in a provided range
'SOURCE: www.TheSpreadsheetGuru.com/the-code-vault
Dim rng As Range
Dim myArray As Variant
Dim x As Integer
'Store Range to search through
Set rng = Range("A1:A3")
'Use UNIQUE Function and store result to an Array variable
myArray = WorksheetFunction.Unique(rng)
'Test Range for Duplicates with COUNTIFS Function
For x = LBound(myArray) To UBound(myArray)
If WorksheetFunction.CountIfs(rng, myArray(x, 1)) > 1 Then
MsgBox "Found more than one value of " & Chr(34) & myArray(1, x) & Chr(34) & _
" in the cell range. Aborting..."
Exit Sub
End If
Next x
MsgBox "No Duplicates Found. Continuing on..."
End Sub
Using VBA Code Found On The Internet
Now that you’ve found some VBA code that could potentially solve your Excel automation problem, what do you do with it? If you don’t necessarily want to learn how to code VBA and are just looking for the fastest way to implement this code into your spreadsheet, I wrote an article (with video) that explains how to get the VBA code you’ve found running on your spreadsheet.
Getting Started Automating Excel
Are you new to VBA and not sure where to begin? Check out my quickstart guide to learning VBA. This article won’t overwhelm you with fancy coding jargon, as it provides you with a simplistic and straightforward approach to the basic things I wish I knew when trying to teach myself how to automate tasks in Excel with VBA Macros.
Also, if you haven’t checked out Excel’s latest automation feature called Power Query, I have put together a beginner’s guide for automating with Excel’s Power Query feature as well! This little-known built-in Excel feature allows you to merge and clean data automatically with little to no coding!
How Do I Modify This To Fit My Specific Needs?
Chances are this post did not give you the exact answer you were looking for. We all have different situations and it’s impossible to account for every particular need one might have. That’s why I want to share with you: My Guide to Getting the Solution to your Problems FAST! In this article, I explain the best strategies I have come up with over the years to get quick answers to complex problems in Excel, PowerPoint, VBA, you name it!
I highly recommend that you check this guide out before asking me or anyone else in the comments section to solve your specific problem. I can guarantee that 9 times out of 10, one of my strategies will get you the answer(s) you are needing faster than it will take me to get back to you with a possible solution. I try my best to help everyone out, but sometimes I don’t have time to fit everyone’s questions in (there never seem to be quite enough hours in the day!).
I wish you the best of luck and I hope this tutorial gets you heading in the right direction!
After 10+ years of creating macros and developing add-ins, I've compiled all the hacks I wish I had known years ago!

Keep Learning
Chris Newman
Chris is a finance professional and Excel MVP recognized by Microsoft since 2016. With his expertise, he founded TheSpreadsheetGuru blog to help fellow Excel users, where he shares his vast creative solutions & expertise. In addition, he has developed over 7 widely-used Excel Add-ins that have been embraced by individuals and companies worldwide.