Highlighting duplicates accross a workbook

Babydum

Board Regular
Joined
Feb 24, 2005
Messages
164
Hi,

i've searched the forum re finding duplicates across many sheets. Column B on each sheet contains customer reference numbers. I need a formula on each line in column A (or a macro to do this) that will return "Dup" if that reference number appears anywhere else on that sheet or in the workbook. "Dup" would need to occur on all instances where there is duplicate (e.g, if there are two occurences of "QWERTY01", both will show a "Dup")

Sheets are imported on a daily basis, so the workbook is growing. That's why I'm thinking maybe code would be better, so that I can run whenever I need to check.

Thanks for any advice
 

Excel Facts

How to fill five years of quarters?
Type 1Q-2023 in a cell. Grab the fill handle and drag down or right. After 4Q-2023, Excel will jump to 1Q-2024. Dash can be any character.
Code:
Public Sub MarkDupes()
Dim WS As Worksheet

For Each WS In Worksheets
    For Rw = 1 To WS.Cells(65536, 2).End(xlUp).Row
        With WS.Cells(Rw, 2)
            If Len(Trim(.Value)) > 0 Then
                If IsDupe(.Value) Then
                    .Offset(0, -1).Value = "Dup"
                End If
            End If
        End With
    Next Rw
Next WS
End Sub

Public Function IsDupe(SrcValue) As Boolean
For Each WS In Worksheets
    If WorksheetFunction.CountIf(WS.Columns("B:B"), SrcValue) > 1 Then
        IsDupe = True
        Exit Function
    End If
Next WS
    IsDupe = False
End Function
 
Upvote 0
Thanks Nimrod,

This code doesn't appear to do anything. I run XL97, don't know if that is a factor.

I made a dummy s/sheet where I put duplicate entries in sheets 1 & 2, but nothing wasreturned in Column A.

Any thoughts?
 
Upvote 0
Sorry, Babydum , first version would only mark dupes if found on same sheet. I misread what you wanted ... try this one :wink:

Code:
Public Sub MarkDupes()
Dim WS As Worksheet

For Each WS In Worksheets
    For Rw = 1 To WS.Cells(65536, 2).End(xlUp).Row
        With WS.Cells(Rw, 2)
            If Len(Trim(.Value)) > 0 Then
                If IsDupe(.Value) Then
                    .Offset(0, -1).Value = "Dup"
                End If
            End If
        End With
    Next Rw
Next WS
End Sub

Public Function IsDupe(SrcValue) As Boolean
Dim DupCnt As Integer
DupCnt = 0
For Each WS In Worksheets
    If WorksheetFunction.CountIf(WS.Columns("B:B"), SrcValue) > 0 Then
        DupCnt = DupCnt + 1
        If DupCnt > 1 Then
            IsDupe = True
            Exit Function
        End If
    End If
Next WS
    IsDupe = False
End Function
 
Upvote 0
Nimrod: Thanks for this, but unfortunately, it still doesn't seem to be working - the egg-timer's on, but it doesn't return "Dup". Sorry. The duplicates column is actually C:C, but i adjusted that in the code as well as changing offset from -1 to -2 (dup still needs to be in A:A), perhaps I did something wrong?

Firefytr: Unfortunately this add-in is for XL2000 and above, but the program needs to be able to be run on some 97 equipped machines.

Thanks both for your help.
 
Upvote 0
Code:
Public Sub MarkDupes()
Dim WS As Worksheet
Dim SrcCol As Integer

' MAKE COLUMN CHANGES HERE !!!
SrcCol = 3
TargCol = 1

For Each WS In Worksheets
    For Rw = 1 To WS.Cells(65536, SrcCol).End(xlUp).Row
        With WS.Cells(Rw, SrcCol)
            If Len(Trim(.Value)) > 0 Then
                If IsDupe(.Value, SrcCol) Then
                    WS.Cells(Rw, TargCol).Value = "Dupe"
                End If
            End If
        End With
    Next Rw
Next WS
End Sub

Public Function IsDupe(SrcValue, Src) As Boolean
Dim DupCnt As Integer
DupCnt = 0
For Each WS In Worksheets
    If WorksheetFunction.CountIf(WS.Cells(1, Src).EntireColumn, SrcValue) > 0 Then
        DupCnt = DupCnt + 1
        If DupCnt > 1 Then
            IsDupe = True
            Exit Function
        End If
    End If
Next WS
    IsDupe = False
End Function
 
Upvote 0

Forum statistics

Threads
1,219,162
Messages
6,146,660
Members
450,706
Latest member
LGVBPP

We've detected that you are using an adblocker.

We have a great community of people providing Excel help here, but the hosting costs are enormous. You can help keep this site running by allowing ads on MrExcel.com.
Allow Ads at MrExcel

Which adblocker are you using?

Disable AdBlock

Follow these easy steps to disable AdBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the icon in the browser’s toolbar.
2)Click on the "Pause on this site" option.
Go back

Disable AdBlock Plus

Follow these easy steps to disable AdBlock Plus

1)Click on the icon in the browser’s toolbar.
2)Click on the toggle to disable it for "mrexcel.com".
Go back

Disable uBlock Origin

Follow these easy steps to disable uBlock Origin

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back

Disable uBlock

Follow these easy steps to disable uBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back
Back
Top