XL2000: Date Returned in a Macro Is Four Years Too Early
ID: Q213593
|
The information in this article applies to:
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, 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 Solution Provider
or the Microsoft fee-based consulting line at (800) 936-5200. For more information about
Microsoft Certified Solution Providers, please see the following page on the World Wide Web:
http://www.microsoft.com/mcsp/
For more information about the support options available from Microsoft, please see the
following page on the World Wide Web:
http://www.microsoft.com/support/supportnet/overview/overview.asp
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.
Additional query words:
XL2000
Keywords : kbprg kbdta kbdtacode xlvbainfo KbVBA
Version : WINDOWS:2000
Platform : WINDOWS
Issue type : kbbug