How can you find multiple match in a cell and select the one with the latest date attribute to it

Jimmy509

New Member
Joined
Apr 18, 2019
Messages
29
Hello my fellow excel-ers,
I am trying to find search through a range of cells in column A from my excel spreadsheet. I know that I can use .Find to find the first match in that range or use .FindNext to find all of them. But my issue is I would like to find the match for my latest transaction. In Column B I have a range of dates for each transaction.
The transaction ID repeat multiple times for different date. I would to select the date that is the most recent.
I am new to excel VBA. Can anyone help me please.
 

Excel Facts

Last used cell?
Press Ctrl+End to move to what Excel thinks is the last used cell.
Maybe something like this (dates as dd/mm/yyyy)


A
B
C
D
E
1
Transaction​
Date​
Transaction​
Last Date​
2
1​
03/01/2019​
1​
03/03/2019​
3
1​
03/03/2019​
2​
10/01/2019​
4
1​
04/02/2019​
3​
10/04/2019​
5
2​
10/01/2019​
6
2​
04/01/2019​
7
3​
11/01/2019​
8
3​
03/03/2019​
9
3​
10/04/2019​
10
3​
02/04/2019​

<tbody>
</tbody>


Array formula in E2 copied down
=MAX(IF(A$2:A$10=D2,B$2:B$10))
confirmed with Ctrl+Shift+Enter, not just Enter

Format column E as Date

Hope this helps

M.
 
Last edited:
Upvote 0
Maybe something like this (dates as dd/mm/yyyy)


A
B
C
D
E
1
Transaction​
Date​
Transaction​
Last Date​
2
1​
03/01/2019​
1​
03/03/2019​
3
1​
03/03/2019​
2​
10/01/2019​
4
1​
04/02/2019​
3​
10/04/2019​
5
2​
10/01/2019​
6
2​
04/01/2019​
7
3​
11/01/2019​
8
3​
03/03/2019​
9
3​
10/04/2019​
10
3​
02/04/2019​

<tbody>
</tbody>


Array formula in E2 copied down
=MAX(IF(A$2:A$10=D2,B$2:B$10))
confirmed with Ctrl+Shift+Enter, not just Enter

Format column E as Date

Hope this helps

M.

Thanks but I was looking for something more like in VBA format
 
Upvote 0
Something using .Find method

Maybe something like this (see data sample in post 6)

Code:
Sub FindMaxDate()
    'From Chip Pearson
    'http://www.cpearson.com/excel/findall.aspx
    Dim DataRange As Range, rCell As Range
    Dim FoundCell As Range, LastCell As Range, FirstAddr As String
    Dim dtMax As Long
    
    Set DataRange = Range("A2:A10")
    With DataRange
        Set LastCell = .Cells(.Cells.Count)
    End With
    
    For Each rCell In Range("D2:D4")
        Set FoundCell = DataRange.Find(what:=rCell, after:=LastCell)
        If Not FoundCell Is Nothing Then
            FirstAddr = FoundCell.Address
            dtMax = FoundCell.Offset(, 1)
        End If
        
        Do Until FoundCell Is Nothing
            Set FoundCell = DataRange.FindNext(after:=FoundCell)
            If FoundCell.Address = FirstAddr Then Exit Do
            If FoundCell.Offset(, 1) > dtMax Then dtMax = FoundCell.Offset(, 1)
        Loop
        With rCell.Offset(, 1)
            .Value = dtMax
            .NumberFormat = "dd/mm/yyyy"
        End With
    Next rCell
End Sub

Hope this helps

M.
 
Upvote 0
Some adjustments:
Change the datatype of dtMax to Variant

Immediately after the For each rCell in Range("D2:D4") insert this line
dtMax = "Not Found"

In the first Find insert this parameter
LookAt:=xlWhole

M.
 
Upvote 0

Forum statistics

Threads
1,213,561
Messages
6,114,317
Members
448,564
Latest member
ED38

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