Introduction.
How to find the number of workdays (excluding Saturdays and Sundays) from a date range in Microsoft Access?
The logic is straightforward: first, determine the number of whole weeks within the specified date range. Multiplying whole weeks by 5 gives the number of workdays from entire weeks. From the remaining days, exclude Saturdays and Sundays, if any. Add the remaining days to the total workdays.
DateDiff() and DateAdd() functions are used for calculations, and the Format() function gets day-of-the-week in the three-character form to find Saturday and Sunday to exclude from the remaining days.
Find the VBA Code segments for the above steps below, and the full VBA Work_Days() Function Code at the end of this Article.
Find the number of Whole Weeks between Begin-Date and End-Date:
WholeWeeks = DateDiff("w", BeginDate, EndDate)The WholeWeeks * 5 (7 - Saturdays & Sundays) will give the number of working days in whole weeks. Now, all that remains is to find how many working days are left in the remaining days, if any.
- Find the date after all the weekdays:
DateCnt = DateAdd("ww", WholeWeeks, BeginDate) - Find the number of workdays in the remaining days by checking and excluding Saturdays and Sundays:
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)'increment the date by 1 Loop Calculate the Total Workdays:
Work_Days = Wholeweeks * 5 + EndDays
The Whole Calculation in the Work_Days Function.
The full VBA Code of the Work_Days() Function is given below:
Function Work_Days(BegDate As Variant, EndDate As Variant) As Integer
Dim WholeWeeks As Variant
Dim DateCnt As Variant
Dim EndDays As Integer
On Error GoTo Err_Work_Days
BegDate = DateValue(BegDate)
EndDate = DateValue(EndDate)
'Number of whole weeks
WholeWeeks = DateDiff("w", BegDate, EndDate)
'Next date after whole weeks of 7 days each
DateCnt = DateAdd("ww", WholeWeeks, BegDate)
EndDays = 0 'to count number of days except Saturday & Sunday
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)'increment the date by 1
Loop
'Calculate total work days and return the result
Work_Days = WholeWeeks * 5 + EndDays
Exit Function
Err_Work_Days:
' If either BegDate or EndDate is Null, return a zero
' to indicate that no workdays passed between the two dates.
If Err.Number = 94 Then
Work_Days = 0
Exit Function
Else
' If some other error occurs, provide a message.
MsgBox "Error " & Err.Number & ": " & Err.Description
End If
End Function
The above VBA Code was taken from the Microsoft Access Help Document.











