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!
 

Joe4

MrExcel MVP, Junior Admin
Joined
Aug 1, 2002
Messages
51,731
Office Version
365
Platform
Windows
Welcome to the Board!

So, will the date always appear at the very beginning or the very end?
 

Norie

Well-known Member
Joined
Apr 28, 2004
Messages
75,392
Office Version
365
Platform
Windows
Is the date always in the same format?
 

Leith Ross

Well-known Member
Joined
Mar 17, 2008
Messages
1,876
Office Version
2010, 2007
Platform
Windows
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
 

tabletopjoe

New Member
Joined
Jan 10, 2018
Messages
6
Welcome to the Board!

So, will the date always appear at the very beginning or the very end?
Thanks Joe4! Sadly not, basically any element of the filename may occur in any position.
 

tabletopjoe

New Member
Joined
Jan 10, 2018
Messages
6
Is the date always in the same format?
Hi Norie, there is some variation with the date formats but I am assuming I can work around those variations once I have a method in place for the standard MMDDYYYY format.
 

tabletopjoe

New Member
Joined
Jan 10, 2018
Messages
6
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
 

Leith Ross

Well-known Member
Joined
Mar 17, 2008
Messages
1,876
Office Version
2010, 2007
Platform
Windows
Hello tabletopjoe,

You're welcome.
 

tabletopjoe

New Member
Joined
Jan 10, 2018
Messages
6
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!
 

Leith Ross

Well-known Member
Joined
Mar 17, 2008
Messages
1,876
Office Version
2010, 2007
Platform
Windows
Hello tabletopjoe,

Glad I could help.
 

Forum statistics

Threads
1,084,889
Messages
5,380,446
Members
401,679
Latest member
saffar

Some videos you may like

This Week's Hot Topics

Top