Return row based on most current date when multiple instances exist in the column.

Cryptzog

New Member
Joined
Dec 7, 2017
Messages
2
Hello all,

First, my apologies if this question already exists. I have looked, but haven't found my particular problem discussed.

Current raw data:
JOE RED 10 MAY 2001
JOE BLUE 10 JUN 2001
JOE GREEN 10 JUL 2001
FRANK RED 10 JUN 2001
FRANK GREEN 10 JUL 2001
FRANK BLUE 10 AUG 2001
FRED GREEN 10 MAY 2002
FRED BLUE 10 JUN 2002
FRED RED 10 JUL 2002

The information I need returned:
JOE GREEN 10 JUL 2001
FRANK RED 10 AUG 2001
FRED RED 10 JUL 2002

(The name, color, and date are in 3 separate columns named "NAME", "COLOR", "DATE".)

As you can see above, I need the row returned of the most current instance (based on the most current date) for each person.

Thanks to everyone who has taken a look at my problem.

-Andrew
 

Excel Facts

Copy PDF to Excel
Select data in PDF. Paste to Microsoft Word. Copy from Word and paste to Excel.
This macro assumes that the dates for each name are sorted from least recent to most recent as in your posted sample data. The results will be in Sheet2.
Code:
Sub getCurrentDate()
    Dim rngUniques As Range
    Dim LastRow As Long
    LastRow = Cells.Find("*", SearchOrder:=xlByRows, SearchDirection:=xlPrevious).Row
    Dim lVisRow As Long
    Range("A1:A" & LastRow).AdvancedFilter Action:=xlFilterInPlace, CriteriaRange:=Range("A1:A" & LastRow), Unique:=True
    Set rngUniques = Range("A2:A" & LastRow).SpecialCells(xlCellTypeVisible)
    Dim rName As Range
    For Each rName In rngUniques
        Range("A1:C" & LastRow).AutoFilter Field:=1, Criteria1:=rName
        lVisRow = Range("A" & Rows.Count).End(xlUp).Row
        Rows(lVisRow).EntireRow.Copy Sheets("Sheet2").Cells(Rows.Count, "A").End(xlUp).Offset(1, 0)
    Next rName
    If ActiveSheet.AutoFilterMode = True Then ActiveSheet.AutoFilterMode = False
End Sub
 
Upvote 0
Not everybody wants a macro. In that case:

Row\Col
A​
B​
C​
E​
F​
G​
1​
namecolordate
3​
2​
JOERED
10-May-01​
namecolordate
3​
JOEBLUE
10-Jun-01​
JOEGREEN
10-Jul-01​
4​
JOEGREEN
10-Jul-01​
FRANKBLUE
10-Aug-01​
5​
FRANKRED
10-Jun-01​
FREDRED
10-Jul-02​
6​
FRANKGREEN
10-Jul-01​
7​
FRANKBLUE
10-Aug-01​
8​
FREDGREEN
10-May-02​
9​
FREDBLUE
10-Jun-02​
10​
FREDRED
10-Jul-02​

In E1 control+shift+enter, not just enter:

=SUM(IF(FREQUENCY(IF(1-(Name=""),MATCH(Name,Name,0)),ROW(Name)-ROW(INDEX(Name,1,1))+1),1))

In E3 control+shift+enter and copy down:

=IF(ROWS($E$3:E3)>$E$1,"",INDEX(Name,SMALL(IF(FREQUENCY(IF(1-(Name=""),MATCH(Name,Name,0)),ROW(Name)-ROW(INDEX(Name,1,1))+1),ROW(Name)-ROW(INDEX(Name,1,1))+1),ROWS($E$3:E3))))

In F3 control+shift+enter and copy down:

=IF($E3="","",INDEX(Color,MATCH($E3,IF(Date=$G3,Name),0)))

In G3 control+shift+enter and copy down:

=IF($E3="","",MAX(IF(Name=$E3,Date)))

In G3 just enter and copy down if there is MAXIFS on your Excel...

=IF($E3="","",MAXIFS(Date,Name,$E3))
 
Upvote 0

Forum statistics

Threads
1,215,222
Messages
6,123,709
Members
449,118
Latest member
MichealRed

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