Delete duplicates of one column based on multiple criteria to keep the oldest entry

smr3313

New Member
Joined
Apr 24, 2018
Messages
4
Hi,

I am new to the forum and decently new to VBA so if this is an easy solution or there are other answers available sorry in advance. I have a fairly large workbook that serves as a sort of action list that is built from user input on a separate sheet. There is the possibility that someone inputs the same action for the same work center on two different dates and I would like to loop through to delete any entry that is not the oldest one. Here is a small sample of what the action list will look like:

[TABLE="width: 767"]
<colgroup><col><col><col><col><col><col><col></colgroup><tbody>[TR]
[TD]Work Center[/TD]
[TD]Responsible[/TD]
[TD]Action[/TD]
[TD]Due[/TD]
[TD]Submitted By[/TD]
[TD]Comment[/TD]
[TD]Submitted On[/TD]
[/TR]
[TR]
[TD]12[/TD]
[TD]DT[/TD]
[TD]A[/TD]
[TD]15-Apr[/TD]
[TD]RW[/TD]
[TD]None[/TD]
[TD]15-Mar[/TD]
[/TR]
[TR]
[TD]12[/TD]
[TD]DT[/TD]
[TD]B[/TD]
[TD]15-Apr[/TD]
[TD]RW[/TD]
[TD]None[/TD]
[TD]15-Mar[/TD]
[/TR]
[TR]
[TD]12[/TD]
[TD]DT[/TD]
[TD]C[/TD]
[TD]15-May[/TD]
[TD]RW[/TD]
[TD]None[/TD]
[TD]15-Mar[/TD]
[/TR]
[TR]
[TD]12[/TD]
[TD]DT[/TD]
[TD]D[/TD]
[TD]15-May[/TD]
[TD]RW[/TD]
[TD]None[/TD]
[TD]15-Mar[/TD]
[/TR]
[TR]
[TD]12[/TD]
[TD]DT[/TD]
[TD]E[/TD]
[TD]15-Jun[/TD]
[TD]RW[/TD]
[TD]None[/TD]
[TD]15-Mar[/TD]
[/TR]
[TR]
[TD]12[/TD]
[TD]DT[/TD]
[TD]F[/TD]
[TD]15-Jun[/TD]
[TD]RW[/TD]
[TD]None[/TD]
[TD]15-Mar[/TD]
[/TR]
[TR]
[TD]12[/TD]
[TD]DT[/TD]
[TD]G[/TD]
[TD]15-Jul[/TD]
[TD]RW[/TD]
[TD]None[/TD]
[TD]15-Mar[/TD]
[/TR]
[TR]
[TD]14[/TD]
[TD]JW[/TD]
[TD]D[/TD]
[TD]20-May[/TD]
[TD]DA[/TD]
[TD]None[/TD]
[TD]20-Apr[/TD]
[/TR]
[TR]
[TD]14[/TD]
[TD]JW[/TD]
[TD]F[/TD]
[TD]20-May[/TD]
[TD]DA[/TD]
[TD]None[/TD]
[TD]20-Apr[/TD]
[/TR]
[TR]
[TD]12[/TD]
[TD]DT[/TD]
[TD]G[/TD]
[TD]20-Jun[/TD]
[TD]DA[/TD]
[TD]None[/TD]
[TD]20-Apr[/TD]
[/TR]
[TR]
[TD]12[/TD]
[TD]DT[/TD]
[TD]H[/TD]
[TD]20-Jun[/TD]
[TD]DA[/TD]
[TD]None[/TD]
[TD]20-Apr[/TD]
[/TR]
</tbody>[/TABLE]

Sorry for the format like I said I am new and am not sure what the accepted way of posting table data is.

In reality there are about 250 work centers and 20 different actions that could possibly be assigned, so this is a very small snippet. The key columns are only work center, action, and submitted on. The criteria for removal is this: if the work center has that same action assigned at a previous date, then the most recent entry should be deleted. For this data set that would remove the second to last line since work center 12 had already been assigned action G on March 15th.
 

Excel Facts

Create a Pivot Table on a Map
If your data has zip codes, postal codes, or city names, select the data and use Insert, 3D Map. (Found to right of chart icons).
Try this:-
Code:
[COLOR=navy]Sub[/COLOR] MG24Apr16
[COLOR=navy]Dim[/COLOR] Rng [COLOR=navy]As[/COLOR] Range, Dn [COLOR=navy]As[/COLOR] Range, n [COLOR=navy]As[/COLOR] [COLOR=navy]Long,[/COLOR] Txt [COLOR=navy]As[/COLOR] [COLOR=navy]String[/COLOR]
[COLOR=navy]Dim[/COLOR] nRng [COLOR=navy]As[/COLOR] Range, Q [COLOR=navy]As[/COLOR] Variant, K [COLOR=navy]As[/COLOR] Variant, R [COLOR=navy]As[/COLOR] Range
[COLOR=navy]Set[/COLOR] Rng = Range("A2", Range("A" & Rows.Count).End(xlUp))
    [COLOR=navy]With[/COLOR] CreateObject("scripting.dictionary")
    .CompareMode = vbTextCompare
[COLOR=navy]For[/COLOR] [COLOR=navy]Each[/COLOR] Dn [COLOR=navy]In[/COLOR] Rng
    Txt = Dn.Value & Dn.Offset(, 2).Value
        [COLOR=navy]If[/COLOR] Not .Exists(Txt) [COLOR=navy]Then[/COLOR]
            .Add Txt, Array(Dn.Offset(, 6).Value, Dn.Offset(, 6))
        [COLOR=navy]Else[/COLOR]
            Q = .Item(Txt)
                [COLOR=navy]If[/COLOR] Dn.Offset(, 6).Value < Q(0) [COLOR=navy]Then[/COLOR] Q(0) = Dn.Offset(, 6).Value
                [COLOR=navy]Set[/COLOR] Q(1) = Union(Q(1), Dn.Offset(, 6))
            .Item(Txt) = Q
       [COLOR=navy]End[/COLOR] If
[COLOR=navy]Next[/COLOR]
[COLOR=navy]For[/COLOR] [COLOR=navy]Each[/COLOR] K [COLOR=navy]In[/COLOR] .keys
  [COLOR=navy]For[/COLOR] [COLOR=navy]Each[/COLOR] R [COLOR=navy]In[/COLOR] .Item(K)(1)
    [COLOR=navy]If[/COLOR] R > .Item(K)(0) [COLOR=navy]Then[/COLOR]
       [COLOR=navy]If[/COLOR] nRng [COLOR=navy]Is[/COLOR] Nothing [COLOR=navy]Then[/COLOR]
            [COLOR=navy]Set[/COLOR] nRng = R
        [COLOR=navy]Else[/COLOR]
           [COLOR=navy]Set[/COLOR] nRng = Union(nRng, R)
        [COLOR=navy]End[/COLOR] If
    [COLOR=navy]End[/COLOR] If
  [COLOR=navy]Next[/COLOR] R
[COLOR=navy]Next[/COLOR] K
[COLOR=navy]If[/COLOR] Not nRng [COLOR=navy]Is[/COLOR] Nothing [COLOR=navy]Then[/COLOR] nRng.EntireRow.Delete
[COLOR=navy]End[/COLOR] [COLOR=navy]With[/COLOR]
[COLOR=navy]End[/COLOR] [COLOR=navy]Sub[/COLOR]
Regards Mick
 
Last edited:
Upvote 0
Try this:-
Code:
[COLOR=navy]Sub[/COLOR] MG24Apr16
[COLOR=navy]Dim[/COLOR] Rng [COLOR=navy]As[/COLOR] Range, Dn [COLOR=navy]As[/COLOR] Range, n [COLOR=navy]As[/COLOR] [COLOR=navy]Long,[/COLOR] Txt [COLOR=navy]As[/COLOR] [COLOR=navy]String[/COLOR]
[COLOR=navy]Dim[/COLOR] nRng [COLOR=navy]As[/COLOR] Range, Q [COLOR=navy]As[/COLOR] Variant, K [COLOR=navy]As[/COLOR] Variant, R [COLOR=navy]As[/COLOR] Range
[COLOR=navy]Set[/COLOR] Rng = Range("A2", Range("A" & Rows.Count).End(xlUp))
    [COLOR=navy]With[/COLOR] CreateObject("scripting.dictionary")
    .CompareMode = vbTextCompare
[COLOR=navy]For[/COLOR] [COLOR=navy]Each[/COLOR] Dn [COLOR=navy]In[/COLOR] Rng
    Txt = Dn.Value & Dn.Offset(, 2).Value
        [COLOR=navy]If[/COLOR] Not .Exists(Txt) [COLOR=navy]Then[/COLOR]
            .Add Txt, Array(Dn.Offset(, 6).Value, Dn.Offset(, 6))
        [COLOR=navy]Else[/COLOR]
            Q = .Item(Txt)
                [COLOR=navy]If[/COLOR] Dn.Offset(, 6).Value < Q(0) [COLOR=navy]Then[/COLOR] Q(0) = Dn.Offset(, 6).Value
                [COLOR=navy]Set[/COLOR] Q(1) = Union(Q(1), Dn.Offset(, 6))
            .Item(Txt) = Q
       [COLOR=navy]End[/COLOR] If
[COLOR=navy]Next[/COLOR]
[COLOR=navy]For[/COLOR] [COLOR=navy]Each[/COLOR] K [COLOR=navy]In[/COLOR] .keys
  [COLOR=navy]For[/COLOR] [COLOR=navy]Each[/COLOR] R [COLOR=navy]In[/COLOR] .Item(K)(1)
    [COLOR=navy]If[/COLOR] R > .Item(K)(0) [COLOR=navy]Then[/COLOR]
       [COLOR=navy]If[/COLOR] nRng [COLOR=navy]Is[/COLOR] Nothing [COLOR=navy]Then[/COLOR]
            [COLOR=navy]Set[/COLOR] nRng = R
        [COLOR=navy]Else[/COLOR]
           [COLOR=navy]Set[/COLOR] nRng = Union(nRng, R)
        [COLOR=navy]End[/COLOR] If
    [COLOR=navy]End[/COLOR] If
  [COLOR=navy]Next[/COLOR] R
[COLOR=navy]Next[/COLOR] K
[COLOR=navy]If[/COLOR] Not nRng [COLOR=navy]Is[/COLOR] Nothing [COLOR=navy]Then[/COLOR] nRng.EntireRow.Delete
[COLOR=navy]End[/COLOR] [COLOR=navy]With[/COLOR]
[COLOR=navy]End[/COLOR] [COLOR=navy]Sub[/COLOR]
Regards Mick

Mick,

Thanks for your timely response. I can't say I understand many of the functions you've used so sorry I can't troubleshoot much on my own. The code runs without error and each loop seems to iterate through every row but then nothing happens. Here is a replica of the exact table I am running the code on, sorry I cannot post attachments.

[TABLE="width: 2028"]
<colgroup><col><col><col><col><col><col><col><col></colgroup><tbody>[TR]
[TD]Work Center[/TD]
[TD]Area[/TD]
[TD]Supervisor[/TD]
[TD]Action[/TD]
[TD]Date[/TD]
[TD]Submitted By[/TD]
[TD]Comment[/TD]
[TD]Submitted On[/TD]
[/TR]
[TR]
[TD]302327[/TD]
[TD]MS[/TD]
[TD]DT[/TD]
[TD]Designate[/TD]
[TD="align: right"]5/24/2018[/TD]
[TD]SR[/TD]
[TD]None[/TD]
[TD="align: right"]4/20/2018[/TD]
[/TR]
[TR]
[TD]302327[/TD]
[TD]MS[/TD]
[TD]DT[/TD]
[TD]Designate[/TD]
[TD="align: right"]5/24/2018[/TD]
[TD]SR[/TD]
[TD]None[/TD]
[TD="align: right"]4/24/2018[/TD]
[/TR]
[TR]
[TD]302327[/TD]
[TD]MS[/TD]
[TD]DT[/TD]
[TD]Tape off[/TD]
[TD="align: right"]5/24/2018[/TD]
[TD]SR[/TD]
[TD]None[/TD]
[TD="align: right"]4/24/2018[/TD]
[/TR]
[TR]
[TD]GV2[/TD]
[TD]GV[/TD]
[TD]DK[/TD]
[TD]Label[/TD]
[TD="align: right"]5/24/2018[/TD]
[TD]SR[/TD]
[TD]None[/TD]
[TD="align: right"]4/23/2018[/TD]
[/TR]
[TR]
[TD]GV2[/TD]
[TD]GV[/TD]
[TD]DK[/TD]
[TD]Label[/TD]
[TD="align: right"]5/24/2018[/TD]
[TD]SR[/TD]
[TD]None[/TD]
[TD="align: right"]4/24/2018[/TD]
[/TR]
[TR]
[TD]303339[/TD]
[TD]MS[/TD]
[TD]JW[/TD]
[TD]Designate[/TD]
[TD="align: right"]5/24/2018[/TD]
[TD]SR[/TD]
[TD]None[/TD]
[TD="align: right"]4/24/2018[/TD]
[/TR]
[TR]
[TD]303339[/TD]
[TD]MS[/TD]
[TD]JW[/TD]
[TD]Label[/TD]
[TD="align: right"]5/24/2018[/TD]
[TD]SR[/TD]
[TD]None[/TD]
[TD="align: right"]4/24/2018[/TD]
[/TR]
[TR]
[TD]GV1[/TD]
[TD]GV[/TD]
[TD]DK[/TD]
[TD]Designate[/TD]
[TD="align: right"]5/24/2018[/TD]
[TD]SR[/TD]
[TD]None[/TD]
[TD="align: right"]4/20/2018[/TD]
[/TR]
[TR]
[TD]303018[/TD]
[TD]MS[/TD]
[TD]JW[/TD]
[TD]Designate[/TD]
[TD="align: right"]5/24/2018[/TD]
[TD]SR[/TD]
[TD]None[/TD]
[TD="align: right"]4/24/2018[/TD]
[/TR]
[TR]
[TD]303018[/TD]
[TD]MS[/TD]
[TD]JW[/TD]
[TD]Tape off[/TD]
[TD="align: right"]5/24/2018[/TD]
[TD]SR[/TD]
[TD]None[/TD]
[TD="align: right"]4/24/2018[/TD]
[/TR]
[TR]
[TD]303018[/TD]
[TD]MS[/TD]
[TD]JW[/TD]
[TD]Label[/TD]
[TD="align: right"]5/24/2018[/TD]
[TD]SR[/TD]
[TD]None[/TD]
[TD="align: right"]4/24/2018[/TD]
[/TR]
[TR]
[TD]GV1[/TD]
[TD]GV[/TD]
[TD]DK[/TD]
[TD]Label[/TD]
[TD="align: right"]5/24/2018[/TD]
[TD]SR[/TD]
[TD]None[/TD]
[TD="align: right"]4/24/2018[/TD]
[/TR]
[TR]
[TD]GV1[/TD]
[TD]GV[/TD]
[TD]DK[/TD]
[TD]Designate[/TD]
[TD="align: right"]5/24/2018[/TD]
[TD]SR[/TD]
[TD]None[/TD]
[TD="align: right"]4/24/2018[/TD]
[/TR]
</tbody>[/TABLE]

Thanks again for your help!
 
Upvote 0
Mick,

Sorry I did not catch this before responding but I realize it is because I added a column between Work center and supervisor that was not there in my sample. Would this change the offset value of 2? That's what it appears to be based on my minimal knowledge of this code, if you have a minute I would be happy to learn a bit about how this works. Once again sorry for the double post and not catching this previously.
 
Upvote 0
Are the criteria columns still "Work Center", Action" and "Submitted on "
 
Last edited:
Upvote 0
On the Criteria above, Try this:-
Code:
[COLOR="Navy"]Sub[/COLOR] MG25Apr06
[COLOR="Navy"]Dim[/COLOR] Rng [COLOR="Navy"]As[/COLOR] Range, Dn [COLOR="Navy"]As[/COLOR] Range, n [COLOR="Navy"]As[/COLOR] [COLOR="Navy"]Long,[/COLOR] Txt [COLOR="Navy"]As[/COLOR] [COLOR="Navy"]String[/COLOR]
[COLOR="Navy"]Dim[/COLOR] nRng [COLOR="Navy"]As[/COLOR] Range, Q [COLOR="Navy"]As[/COLOR] Variant, K [COLOR="Navy"]As[/COLOR] Variant, r [COLOR="Navy"]As[/COLOR] Range
[COLOR="Navy"]Set[/COLOR] Rng = Range("A2", Range("A" & Rows.Count).End(xlUp))
    [COLOR="Navy"]With[/COLOR] CreateObject("scripting.dictionary")
    .CompareMode = vbTextCompare
[COLOR="Navy"]For[/COLOR] [COLOR="Navy"]Each[/COLOR] Dn [COLOR="Navy"]In[/COLOR] Rng
    Txt = Dn.Value & Dn.Offset(, 3).Value
        [COLOR="Navy"]If[/COLOR] Not .Exists(Txt) [COLOR="Navy"]Then[/COLOR]
            .Add Txt, Array(Dn.Offset(, 7).Value, Dn.Offset(, 7))
        [COLOR="Navy"]Else[/COLOR]
            Q = .Item(Txt)
                [COLOR="Navy"]If[/COLOR] Dn.Offset(, 7).Value < Q(0) [COLOR="Navy"]Then[/COLOR] Q(0) = Dn.Offset(, 7).Value
                [COLOR="Navy"]Set[/COLOR] Q(1) = Union(Q(1), Dn.Offset(, 7))
            .Item(Txt) = Q
    [COLOR="Navy"]End[/COLOR] If
[COLOR="Navy"]Next[/COLOR]
[COLOR="Navy"]For[/COLOR] [COLOR="Navy"]Each[/COLOR] K [COLOR="Navy"]In[/COLOR] .keys
  [COLOR="Navy"]For[/COLOR] [COLOR="Navy"]Each[/COLOR] r [COLOR="Navy"]In[/COLOR] .Item(K)(1)
    [COLOR="Navy"]If[/COLOR] r > .Item(K)(0) [COLOR="Navy"]Then[/COLOR]
       [COLOR="Navy"]If[/COLOR] nRng [COLOR="Navy"]Is[/COLOR] Nothing [COLOR="Navy"]Then[/COLOR]
            [COLOR="Navy"]Set[/COLOR] nRng = r
        [COLOR="Navy"]Else[/COLOR]
           [COLOR="Navy"]Set[/COLOR] nRng = Union(nRng, r)
        [COLOR="Navy"]End[/COLOR] If
    [COLOR="Navy"]End[/COLOR] If
  [COLOR="Navy"]Next[/COLOR] r
[COLOR="Navy"]Next[/COLOR] K
[COLOR="Navy"]If[/COLOR] Not nRng [COLOR="Navy"]Is[/COLOR] Nothing [COLOR="Navy"]Then[/COLOR] nRng.EntireRow.Delete
[COLOR="Navy"]End[/COLOR] With
[COLOR="Navy"]End[/COLOR] [COLOR="Navy"]Sub[/COLOR]
Regards Mick
 
Upvote 0

Forum statistics

Threads
1,223,637
Messages
6,173,488
Members
452,515
Latest member
archcalx

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