How to Check for Duplicates and Display a Count MsgBox

dreen

New Member
Joined
Nov 20, 2019
Messages
39
I have Three worksheets, and essentially I want to select a cell in Column A of Sheet 2 (As the Active Cell) and check if there are any duplicates in Column A of Sheet 3 (The Range for this Sheet should be from A1 to the last row of Data).
If there are any duplicates, I would like a msgbox to display the number of duplicate values if it's greater than 3.
I have added comments explaining my logic in each step, please feel free to simplify my code as well:

VBA Code:
Sub Check_Duplicates()

    'Declaring variables
    Dim Cell As Variant
    Dim Source As Range
    Dim sh1 As Worksheet, sh2 As Worksheet, sh3 As Worksheet
    Dim rowAC As Long
    Dim Counter As Long

    'Assigning a worksheet to the decalred variables
    Set sh1 = Sheet1
    Set sh2 = Sheet2
    Set sh3 = Sheet3

    'Sets the Long variable as the Active Cell Row in Sheet 2
    rowAC = ActiveCell.Row

    'Initializing "Source" variable range to last row in Sheet 3
    'Set Source = sh3.Range("A1").End(xlDown)
    Set Source = sh3.Range("A1", sh3.Range("A1").End(xlDown)) 'StackOverFlow Suggestion
    
    'Looping through each cell in the "Source" variable Range
    For Each Cell In Source
    
        'Checking if the "Cell" values in Sheet 3 (in column A to the last row) are equal to the value in the Active Cell in Column A
        If Cell.Value = sh2.Range("A" & rowAC).Value Then
        'If Cell.Value = sh2.Range("MyRange").Value Then
            
            'Checking whether the value in "Cell" already exists in the "Source" range
            If Application.WorksheetFunction.CountIf(Source, Cell) > 1 Then
                
                'Counts and stores the number of duplicate values from Sheet 3 "Cells" compared to the Active Cell value in Sheet 1 Column A
                Counter = Application.WorksheetFunction.CountIf(sh3.Range("Source,Cell"), sh2.Range("A" & rowAC))
                
                'If there are more than 3 duplicates then display a message box
                If Counter > 3 Then
                
                    'Msgbox displaying the number of duplicate values in Sheet 3
                    MsgBox "No. of duplicates is:" & Counter
                
                End If
            
            End If
        
        End If
        
    Next

End Sub
Currently, my code gets to the first IF Statement and simply goes to the End IF, so it doesn't execute past this line and simply goes to Next and then End Sub:

Code:
 If Cell.Value = sh2.Range("A" & rowAC).Value Then
Cross Referencing:

 
Last edited:

Some videos you may like

Excel Facts

Can a formula spear through sheets?
Use =SUM(January:December!E7) to sum E7 on all of the sheets from January through December

NoSparks

Well-known Member
Joined
Mar 15, 2013
Messages
888
Office Version
2010
Platform
Windows
No need to loop, can just use CountIf against the range,
VBA Code:
Counter = Application.WorksheetFunction.CountIf(Source, sh2.Range("A" & rowAC))
 

dreen

New Member
Joined
Nov 20, 2019
Messages
39
No need to loop, can just use CountIf against the range,
VBA Code:
Counter = Application.WorksheetFunction.CountIf(Source, sh2.Range("A" & rowAC))
Okay I understand that, but I get an error at
VBA Code:
If Cell.Value = sh2.Range("A" & rowAC) Then
because I haven't defined where "Cell" is, how can I do this?
 

NoSparks

Well-known Member
Joined
Mar 15, 2013
Messages
888
Office Version
2010
Platform
Windows
Unless I'm missing something I don't see why you would be using that.
VBA Code:
Sub Check_Duplicates()
    'Declaring variables
    Dim Source As Range
    Dim sh1 As Worksheet, sh2 As Worksheet, sh3 As Worksheet
    Dim rowAC As Long, Counter As Long

    'Assigning a worksheet to the decalred variables
    Set sh1 = Sheet1
    Set sh2 = Sheet2
    Set sh3 = Sheet3

    'Sets the Long variable as the Active Cell Row in Sheet 2
    rowAC = ActiveCell.Row

    'Initializing "Source" variable range to last row in Sheet 3
    Set Source = sh3.Range("A1", sh3.Range("A" & Rows.Count).End(xlUp))
    
    'count number of times is in Source range
    Counter = Application.WorksheetFunction.CountIf(Source, sh2.Range("A" & rowAC))
    
    'If there are more than 3 duplicates then display a message box
    If Counter > 3 Then
        'Msgbox displaying the number of duplicate values in Sheet 3
        MsgBox "No. of duplicates is: " & Counter
    End If
End Sub
 

dreen

New Member
Joined
Nov 20, 2019
Messages
39
Unless I'm missing something I don't see why you would be using that.
VBA Code:
Sub Check_Duplicates()
    'Declaring variables
    Dim Source As Range
    Dim sh1 As Worksheet, sh2 As Worksheet, sh3 As Worksheet
    Dim rowAC As Long, Counter As Long

    'Assigning a worksheet to the decalred variables
    Set sh1 = Sheet1
    Set sh2 = Sheet2
    Set sh3 = Sheet3

    'Sets the Long variable as the Active Cell Row in Sheet 2
    rowAC = ActiveCell.Row

    'Initializing "Source" variable range to last row in Sheet 3
    Set Source = sh3.Range("A1", sh3.Range("A" & Rows.Count).End(xlUp))
   
    'count number of times is in Source range
    Counter = Application.WorksheetFunction.CountIf(Source, sh2.Range("A" & rowAC))
   
    'If there are more than 3 duplicates then display a message box
    If Counter > 3 Then
        'Msgbox displaying the number of duplicate values in Sheet 3
        MsgBox "No. of duplicates is: " & Counter
    End If
End Sub
This works well, very elegant solution, thank you for your help! I'm also glad that the loop was eliminated as I found it to serve no function but couldn't quite figure out how to omit it.
 

NoSparks

Well-known Member
Joined
Mar 15, 2013
Messages
888
Office Version
2010
Platform
Windows
Glad to have helped, thanks for the feedback.
 

Watch MrExcel Video

Forum statistics

Threads
1,099,372
Messages
5,468,233
Members
406,574
Latest member
HeinrichPaul

This Week's Hot Topics

Top