XL2000: Sample Code to Use a Date Range with NETWORKDAYS (213182)
The information in this article applies to:
This article was previously published under Q213182 SUMMARY
When you use the NETWORKDAYS function to specify a range of dates for the Holidays argument, you must either type the dates in a range of cells or enclose the dates with array brackets ({}).
This article includes a Visual Basic for Applications function that allows
you to type a beginning date and an ending date for a consecutive range of
dates. The function returns the entire array of dates between the
beginning and ending dates, and can be used with the Holidays argument of the NETWORKDAYS function.
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:
The following function returns an array of date values from the beginning
date (BegDate) through the ending date (EndDate):
Function DateSpan(BegDate As Date, EndDate As Date) As Variant
Dim DateArray() As Variant, i As Integer, Span As Integer
BegDate = DateValue(BegDate)
EndDate = DateValue(EndDate)
Span = EndDate - BegDate + 1
ReDim DateArray(1 To Span)
For i = 1 To Span
DateArray(i) = BegDate + i - 1
Next
DateSpan = DateArray
End Function
Example Using the Function with NETWORKDAYS
This example returns the number of workdays (weekdays) between December
1, 1998 and January 1, 1999, with the dates between December 24 and January
1 indicated as holidays.
NOTE: Before using the NETWORKDAYS function, you must install the Analysis Toolpak add-in.
- In a new workbook, type the custom function DateSpan (illustrated above) into a new module sheet.
- In Sheet1, type the following formula into cell A1:
=NETWORKDAYS(DATEVALUE("12/1/98"), DATEVALUE("1/1/99"), DateSpan("12/24/98","1/1/99"))
The result is 17 days, the number of days, excluding weekends and
holidays, within the specified date range.
REFERENCESFor more information about the Networkdays function, click Microsoft Excel Help on the Help menu, type networkdays worksheet function in the Office Assistant or the Answer Wizard, and then click Search to view the topic.
Modification Type: | Minor | Last Reviewed: | 10/11/2006 |
---|
Keywords: | kbdtacode kbhowto kbinfo KB213182 |
---|
|