Date Returned in a Macro Is Four Years Too Early (157035)
The information in this article applies to:
- Microsoft Excel 2000
- Microsoft Excel 97 for Windows
- Microsoft Excel for Windows 95
This article was previously published under Q157035 SYMPTOMS
When you run a macro that uses a date from a worksheet cell, the date
returned by the macro may be four years and one day earlier than the actual
date.
CAUSE
A macro returns a date that is four years and one day earlier when you
select "1904 date system" in the Calculation tab of the Options dialog box,
and one of the following conditions is true:
- The macro uses the Value2 property when it stores the date.
-or-
- The macro uses a function in the Microsoft Excel application
library when it stores the date.
WORKAROUND
The following macro determines whether the 1904 date system is selected,
converts a date to the 1900 date system, and returns the expected date.
Microsoft provides programming examples for illustration only, without warranty either expressed or implied. This includes, but is not limited to, the implied warranties of merchantability or fitness for a particular purpose. This article assumes that you are familiar with the programming language that is being demonstrated and with the tools that are used to create and to debug procedures. Microsoft support engineers 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 requirements.
To use the macro, follow these steps:
- To insert a new workbook, click New on the File menu, click workbook,
and then click OK.
- On the Tools menu, click Options, click the Calculation tab, and then
click "1904 date system." Then, click OK.
- Type the following dates in Sheet1:
A1: 7/5/96
A2: 5/11/96
A3: 4/28/96 - On the Tools menu, point to Macro and click Visual Basic Editor. In the
Visual Basic Editor, click Module on the Insert menu.
- Type the following code into the module sheet:
Sub DateTest()
'dimension date variable
Dim dDate As Date
'store minimum date in range into variable
dDate = Application.Min(Worksheets(1).Range("A1:A3"))
'display stored date
MsgBox "Stored date" & Chr(13) & dDate
'check for 1904 date system
If Application.ThisWorkbook.Date1904 Then
'convert 1904 base date to 1900 base date
dDate = DateSerial(Year(dDate) + 4, Month(dDate), Day(dDate) + 1)
'display converted date
MsgBox "Converted date" & Chr(13) & dDate
Else
MsgBox "1904 date system is not enabled"
End If
End Sub
- To run the macro, point to Macro on the Tools menu, and click Macro.
Select DateTest and click Run.
The first message box appears with a date 4/27/92, which is four years and
one day earlier than the earliest date in the range of cells A1 to A3. The
second message box displays the correct "converted" date of 4/28/96.
STATUS
Microsoft has confirmed this to be a problem in the Microsoft products
listed at the beginning of this article.
MORE INFORMATION
Visual Basic for Applications does not automatically detect the 1904 date
system and convert the date as necessary. If a user selects the 1904 date
system in Microsoft Excel, and runs a macro that reads a date from a
worksheet cell, the difference may be four years and one day (the extra one
day accounts for the leap year). For example, a date of 9/1/96 in the 1904
date system may return a date of 8/31/92.
The date system discrepancy may occur in Visual Basic when you select the
1904 date system and the macro uses the Value2 property when it stores the
date.
The Value2 property is a new property in Visual Basic that you can use in
Microsoft Office 97. The Value2 property stores variables in the same way
as the Value property except that it does not use the Currency or Date data
types.
Modification Type: | Minor | Last Reviewed: | 10/10/2006 |
---|
Keywords: | kbdtacode kbprb kbProgramming KB157035 |
---|
|