ACC2000: How to Find Number of Working Days Between Two Dates

ID: Q210562


The information in this article applies to:

Moderate: Requires basic macro, coding, and interoperability skills.

This article applies to a Microsoft Access database (.mdb) and a Microsoft Access project (.adp).


SUMMARY

This article shows you how to calculate the number of working days between two dates.


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 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
Microsoft Access does not have a built-in function to determine the number of working days between two given dates. To determine this, you need to call a user-defined function. The following function includes the start date and the end date; so, the number of days between 02/02/99 and 02/03/99 equals one. Create a module and type the following line in the Declarations section if it is not already there:

Option Explicit 
Type the following procedure:


Function Work_Days(BegDate As Variant, EndDate As Variant) As Integer

   ' Note that this function does not account for holidays.

   Dim WholeWeeks As Variant
   Dim DateCnt As Variant
   Dim EndDays As Integer

   BegDate = DateValue(BegDate)
   EndDate = DateValue(EndDate)
   WholeWeeks = DateDiff("w", BegDate, EndDate)
   DateCnt = DateAdd("ww", WholeWeeks, BegDate)
   EndDays = 0
   Do While DateCnt < EndDate
      If Format(DateCnt, "ddd") <> "Sun" And _
        Format(DateCnt, "ddd") <> "Sat" Then
         EndDays = EndDays + 1
      End If
      DateCnt = DateAdd("d", 1, DateCnt)
   Loop
   Work_Days = WholeWeeks * 5 + EndDays

End Function 
To call the function, you can pass either a valid string or an actual date value. The following are two ways to call this function from the Immediate window:

?Work_Days("01/01/1996", "12/31/1999") 
The date range above returns 1042.

?Work_Days(#03/05/1999#, #04/06/1999#) 
The date range above returns 22.

Additional query words: inf modules day/time workday determine


Keywords          : kbprg kbdta AccCon KbVBA 
Version           : WINDOWS:2000
Platform          : WINDOWS 
Issue type        : kbhowto 

Last Reviewed: July 6, 1999