XL: Using Application.Match to Locate Date Values on a Worksheet

Last reviewed: February 3, 1998
Article ID: Q141507
The information in this article applies to:
  • Microsoft Excel for Windows, versions 5.0, 5.0a, 5.0c
  • Microsoft Excel for Windows NT, version 5.0
  • Microsoft Excel for the Macintosh, versions 5.0, 5.0a
  • Microsoft Excel for Windows 95, versions 7.0, 7.0a
  • Microsoft Excel 97 for Windows
  • Microsoft Excel 98 Macintosh Edition

SUMMARY

In Microsoft Excel, you may run into problems if you use the Match method in a Microsoft Visual Basic for Applications macro or procedure to locate date values on a worksheet. When you use a macro to search for dates, you need to search for the actual serial value of the date.

MORE INFORMATION

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 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 needs. If you have limited programming experience, you may want to contact the Microsoft fee-based consulting line at (800) 936-5200. 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/refguide/default.asp

In Microsoft Excel, each date is represented by a serialized number. If you are using the 1900 date system in Microsoft Excel 5.0 and 7.0, the serial numbers range from 1 to 65,380, corresponding to the dates January 1, 1900, through December 31, 2078. In Microsoft Excel 97 and Microsoft Excel 98, the range has been increased from 1 to 2958465, corresponding to the dates January 1, 1900, through December 31, 9999. If you are using the 1904 date system in versions 5.0 and 7.0, the serial numbers range from 0 to 63,918, corresponding to the dates January 1, 1904, through December 31, 2078. In Microsoft Excel 97 and Microsoft Excel 98, the range is from 1 to 2957003, corresponding to January 1, 1904, through December 31, 9999.

To use a macro to match a date, use the serial value for the date as the lookup value when you use the Match function. You can acquire the serial value for a date by using the CLng function to convert the date to a long integer.

Sample Visual Basic Procedure

   Sub MatchDate()

       Dim TheDate As Date
       Dim Index As Variant

       TheDate = #1/3/95#

       ' Find a match for the serial value of the date in the range A1:A10
       ' on Sheet1.
       Index = Application.Match(CLng(TheDate), Range("Sheet1!A1:A10"), 0)

       ' Display the results.
       If IsError(Index) Then
           MsgBox "Not Found"
       Else
           MsgBox "Match item: " & Index
       End If

   End Sub


Additional query words: XL98 XL97 XL7 XL5 8.00 7.00 5.00 5.00a 5.00c index
match
Keywords : kbcode kbprg PgmHowto
Version : WINDOWS:5.0,5.0c,7.0,97; MACINTOSH:5.0,5.0a,98
Platform : MACINTOSH WINDOWS
Issue type : kbhowto


THE INFORMATION PROVIDED IN THE MICROSOFT KNOWLEDGE BASE IS PROVIDED "AS IS" WITHOUT WARRANTY OF ANY KIND. MICROSOFT DISCLAIMS ALL WARRANTIES, EITHER EXPRESS OR IMPLIED, INCLUDING THE WARRANTIES OF MERCHANTABILITY AND FITNESS FOR A PARTICULAR PURPOSE. IN NO EVENT SHALL MICROSOFT CORPORATION OR ITS SUPPLIERS BE LIABLE FOR ANY DAMAGES WHATSOEVER INCLUDING DIRECT, INDIRECT, INCIDENTAL, CONSEQUENTIAL, LOSS OF BUSINESS PROFITS OR SPECIAL DAMAGES, EVEN IF MICROSOFT CORPORATION OR ITS SUPPLIERS HAVE BEEN ADVISED OF THE POSSIBILITY OF SUCH DAMAGES. SOME STATES DO NOT ALLOW THE EXCLUSION OR LIMITATION OF LIABILITY FOR CONSEQUENTIAL OR INCIDENTAL DAMAGES SO THE FOREGOING LIMITATION MAY NOT APPLY.

Last reviewed: February 3, 1998
© 1998 Microsoft Corporation. All rights reserved. Terms of Use.