vba help - find max date

Mallesh23

Well-known Member
Joined
Feb 4, 2009
Messages
976
Office Version
  1. 2010
Platform
  1. Windows
Hi Team,

Need vba help to split and find max date.

Column A is input Column , expected outputis Column B.

Book1
AB
1DateMax Date
230-01-2020/02-09-2019/16-09-201930/01/2020
304-09-2019/18-09-2019/14-10-2019/23-01-202023/01/2020
418-09-2019/30-09-2019/05-11-2019/23-01-202023/01/2020
516-09-2019/25-09-2019/04-11-201904/11/2019
601-10-2019/23-01-2020/09-10-2019/04-11-201923/01/2020
701-10-2019/28-10-2019/30-01-2020/11-11-201930/01/2020
803-02-2020/01-10-2019/30-01-202003/02/2020
Sheet1



Thanks
mg
 
try this

VBA Code:
Sub test()

    Dim ar As Variant
    Dim i As Long
    Dim maxdate As Date
    Dim arrdate As Long
    
    For i = 2 To 10
   arrdate = 0
        If Cells(i, 1).Value <> "" And Len(Cells(i, 1).Value) > 5 Then
            ar = Split(Cells(i, 1).Value, "/")
                For d = LBound(ar) To UBound(ar)
                If CDate(ar(d)) > arrdate Then
                    arrdate = CDate(ar(d))
                End If
                  
                Next
                 maxdate = arrdate
                Cells(i, 2).Value = maxdate
        End If
  
    Next i

End Sub
 
Upvote 0

Excel Facts

Why does 9 mean SUM in SUBTOTAL?
It is because Sum is the 9th alphabetically in Average, Count, CountA, Max, Min, Product, StDev.S, StDev.P, Sum, VAR.S, VAR.P.
I have data of more than 1 lakh rows.

.... speed is concerned.
Given the above, you may wish to try this version which for me is almost 10 times faster. With 80,000 rows of data like the samples, 0.47 secs v 4.4 secs

VBA Code:
Sub Max_Date_v2()
  Dim a As Variant, b As Variant, itm As Variant
  Dim i As Long, Mx As Long
  
  a = Range("A2", Range("A" & Rows.Count).End(xlUp)).Value
  ReDim b(1 To UBound(a), 1 To 1)
  For i = 1 To UBound(a)
    If Len(a(i, 1)) > 9 Then
      Mx = 0
      For Each itm In Split(a(i, 1), "/")
        If CDate(itm) > Mx Then Mx = CDate(itm)
      Next itm
      b(i, 1) = Mx
    End If
  Next i
  With Range("B2").Resize(UBound(b))
    .NumberFormat = "dd/mm/yyyy"
    .Value = b
  End With
End Sub
 
Upvote 0
Hi Peter,

Thanks for sharing one more option , millions of thanks for your help.
I liked the code. (y) ?


Thanks
mg
 
Upvote 0
Cheers. Actually I posted a version that I didn't mean to. It works fine, but I had meant to post this one which has a couple of minor changes.

VBA Code:
Sub Max_Date_v3()
  Dim a As Variant, b As Variant, itm As Variant
  Dim i As Long
  Dim dMax As Date
  
  a = Range("A2", Range("A" & Rows.Count).End(xlUp)).Value
  ReDim b(1 To UBound(a), 1 To 1)
  For i = 1 To UBound(a)
    If Len(a(i, 1)) > 9 Then
      dMax = 0
      For Each itm In Split(a(i, 1), "/")
        If CDate(itm) > dMax Then dMax = CDate(itm)
      Next itm
      b(i, 1) = dMax
    End If
  Next i
  Range("B2").Resize(UBound(b)).Value = b
End Sub
 
Upvote 0
Hi Peter,

Thanks once again , it also worked !
I like your approach storing output in Array and printing later in excel, in one go. ? (y)



Thanks
mg
 
Upvote 0
I like your approach storing output in Array and printing later in excel, in one go.
Reading all the original values into an array in one go, storing all the results in an array & printing it once to the sheet is why this code is so much faster than the other one. This code only interacts with the worksheet only twice as just described. The other code interacts with the worksheet 4 times per row (or twice if blank or dash) so for 80,000 rows there are between 160,000 and 320,000 code/worksheet interactions compared to 2.
 
Upvote 0

Forum statistics

Threads
1,213,529
Messages
6,114,155
Members
448,554
Latest member
Gleisner2

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