VBA Extracting Date from String

tabletopjoe

New Member
Joined
Jan 10, 2018
Messages
6
Hello, I am creating a macro that regularizes file names and I'm having difficulty assigning the dates within filenames to a variable. The file names look something like this:

"Grants Report S-17, First Response, dated 3-14-2015"

Alternatively they might look like this:

"3-14-2015 1st Response from Mike to Grants Report S-17"

And so forth. The only piece I'm missing is how to dynamically extract dates from the filenames. Their format varies a bit, but I can work around those variations and I am just looking for ways to identify MMDDYYYY out of any particular string and assign that date to a variable. The resulting DateVariable is concatenated along with the rest of the filename's pieces like this:

Code:
ResultName = ReportNum & ResponseNum & " " & ResponseSource & " " & DateVariable

Any tips & tricks are most appreciated!
 

Excel Facts

Which lookup functions find a value equal or greater than the lookup value?
MATCH uses -1 to find larger value (lookup table must be sorted ZA). XLOOKUP uses 1 to find values greater and does not need to be sorted.
Welcome to the Board!

So, will the date always appear at the very beginning or the very end?
 
Upvote 0
Is the date always in the same format?
 
Upvote 0
Hello tabletopjoe,

This VBA macro will return the first occurrence of date string in the format you have shown from a string of text.

Code:
Function ParseDate(ByVal Text As String) As Variant


    Dim Match  As Object
    Dim RegExp As Object
    
        Set RegExp = CreateObject("VBScript.RegExp")
        
        RegExp.Pattern = "(\d{1,2}\-\d{1,2}\-\d{4})"
        Set Match = RegExp.Execute(Text)
        
        If Match.Count > 0 Then ParseDate = Match(0).SubMatches(0)
        
End Function
 
Upvote 0
Hello tabletopjoe,

This VBA macro will return the first occurrence of date string in the format you have shown from a string of text.

Code:
Function ParseDate(ByVal Text As String) As Variant


    Dim Match  As Object
    Dim RegExp As Object
    
        Set RegExp = CreateObject("VBScript.RegExp")
        
        RegExp.Pattern = "(\d{1,2}\-\d{1,2}\-\d{4})"
        Set Match = RegExp.Execute(Text)
        
        If Match.Count > 0 Then ParseDate = Match(0).SubMatches(0)
        
End Function

Hi Leith, thank you very much for your macro example. I will be able to dig into this tomorrow and I'll be sure to let you know if that was the solution I needed.

Best regards
 
Upvote 0
Hi Leith, thank you very much for your macro example. I will be able to dig into this tomorrow and I'll be sure to let you know if that was the solution I needed.

Best regards

It looks like this Regular Expression pattern matching is a very powerful toolset, and precisely what I was looking for - in this context as well as another problem I was tinkering with. Thanks again!
 
Upvote 0

Forum statistics

Threads
1,224,823
Messages
6,181,184
Members
453,020
Latest member
Mohamed Magdi Tawfiq Emam

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