Sample Functions to Parse Numbers and Strings into Dates (185732)
The information in this article applies to:
- Microsoft Visual Basic for Applications 5.0
This article was previously published under Q185732 SUMMARY
This article provides two functions that parse strings or numbers into a
date based on a format mask.
MORE INFORMATIONMicrosoft provides programming examples for illustration only, without warranty either
expressed or implied, including, but not limited to, the implied warranties of
merchantability and/or fitness for a particular purpose. This article assumes
that you are familiar with the programming language being demonstrated and the
tools used to create and debug procedures. Microsoft support professionals can
help explain the functionality of a particular procedure, but they will not
modify these examples to provide added functionality or construct procedures to
meet your specific needs. If you have limited programming experience, you may
want to contact a Microsoft Certified Partner or the Microsoft fee-based
consulting line at (800) 936-5200. For more information about Microsoft Certified
Partners, please visit the following Microsoft Web site:
For more information about the support options that are available and about how to contact Microsoft, visit the following Microsoft Web site:
When retrieving date values from legacy systems, the data may not be in a
format supported by the CDate() function for converting other data types to
date values. The functions below convert strings and numbers to date values
based on a mask passed as an additional argument. The functions return NULL
if an invalid mask is passed and a run-time error if a value is passed
representing an invalid date.
Num2Date converts a number to a date.
String2Date converts a string to a date.
Masks supported by Num2Date:
MMDDYY MMDDYYYY
DDMMYY DDMMYYYY
YYMMDD YYYYMMDD
Masks supported by String2Date:
MMDDYY MMDDYYYY MM/DD/YY MM/DD/YYYY M/D/Y M/D/YY M/D/YYYY
DDMMYY DDMMYYYY DD/MM/YY DD/MM/YYYY DD-MMM-YY DD-MMM-YYYY
YYMMDD YYYYMMDD YY/MM/DD YYYY/MM/DD
Example- Create a new VBA project and add a Module.
- Add the following code to the module:
Function Num2Date (ByVal N As Long, ByVal Fmt As String) As Variant
Select Case Fmt
Case "MMDDYY" '052793
Num2Date = CDate(N \ 10000 & "/" & N \ 100 Mod 100 & _
"/" & N Mod 100)
Case "MMDDYYYY" '05271993
Num2Date = CDate(N \ 1000000 & "/" & N \ 10000 Mod 100 & _
"/" & N Mod 10000)
Case "DDMMYY" '270593
Num2Date = CDate(N \ 100 Mod 100 & "/" & N \ 10000 & _
"/" & N Mod 100)
Case "DDMMYYYY" '27051993
Num2Date = CDate(N \ 10000 Mod 100 & "/" & N \ 1000000 & _
"/" & N Mod 10000)
Case "YYMMDD", "YYYYMMDD" '930527 19930527
Num2Date = CDate(N \ 100 Mod 100 & "/" & N Mod 100 & "/" & _
N \ 10000)
Case Else
Num2Date = Null
End Select
End Function
Function String2Date (ByVal S As String, _
ByVal Fmt As String) As Variant
Select Case Fmt
Case "MMDDYY", "MMDDYYYY" '052793 05271993
String2Date = CDate(Left(S, 2) & "/" & Mid(S, 3, 2) & "/" & _
Mid(S, 5))
Case "DDMMYY", "DDMMYYYY" '270593 27051993
String2Date = CDate(Mid(S, 3, 2) & "/" & Left(S, 2) & "/" & _
Mid(S, 5))
Case "YYMMDD" '930527
String2Date = CDate(Mid(S, 3, 2) & "/" & Right(S, 2) & "/" & _
Left(S, 2))
Case "YYYYMMDD" '19930527
String2Date = CDate(Mid(S, 5, 2) & "/" & Right(S, 2) & "/" & _
Left(S, 4))
Case "MM/DD/YY", "MM/DD/YYYY", "M/D/Y", "M/D/YY", "M/D/YYYY", _
"DD-MMM-YY", "DD-MMM-YYYY"
String2Date = CDate(S)
Case "DD/MM/YY", "DD/MM/YYYY" '27/05/93 27/05/1993
String2Date = CDate(Mid(S, 4, 3) & Left(S, 3) & Mid(S, 7))
Case "YY/MM/DD" '93/05/27
String2Date = CDate(Mid(S, 4, 3) & Right(S, 2) & _
"/" & Left(S, 2))
Case "YYYY/MM/DD" '1993/05/27
String2Date = CDate(Mid(S, 6, 3) & Right(S, 2) & _
"/" & Left(S, 4))
Case Else
String2Date = Null
End Select
End Function
- Run the project and then pause it.
- You can test the function in the Debug or Immediate window:
?Num2Date(19980203, "YYYYMMDD")
#2/3/98#
?String2Date("020398", "MMDDYY")
#2/3/98#
or in code:
Dim D1 As Date, D2 As Date
D1 = Num2Date(19980203, "YYYYMMDD")
D2 = String2Date("020398", "MMDDYY")
NOTE: As with any date conversion function, if only 2 digits of the year
are supplied, you have the potential problem of distinguishing dates in the
1900s versus the 2000s. This can result in problems when calculating
intervals for loan repayments, and so forth, when comparing two dates in
different centuries. If only 2-digit years are supplied, the conversion
functions adhere to the default "smart century" assumptions of the version
of VBA that you are using. If you want to alter this behavior, you can
easily modify the expressions for the appropriate masks.
REFERENCES
For additional information, please see the following
articles in the Microsoft Knowledge Base:
88657 ACC: Functions for Calculating and Displaying Date/Time
Values
100136 ACC: Two Functions to Calculate Age in Months and Years
Modification Type: | Major | Last Reviewed: | 6/17/2005 |
---|
Keywords: | kbhowto KB185732 |
---|
|