Please Note: This article is written for users of the following Microsoft Excel versions: 97, 2000, 2002, and 2003. If you are using a later version (Excel 2007 or later), this tip may not work for you. For a version of this tip written specifically for later versions of Excel, click here: The Last Business Day.
Written by Allen Wyatt (last updated May 3, 2022)
This tip applies to Excel 97, 2000, 2002, and 2003
When developing a worksheet, you may have a need to know the last business day of a given month. Assuming that your business days run Monday through Friday, the following formula will return the desired date:
=DATE(YEAR(A1),MONTH(A1)+1,0)-(MAX(0,WEEKDAY (DATE(YEAR(A1),MONTH(A1)+1,0),2)-5))
This formula returns a date that is only a Monday through Friday, and always the last such day in the month represented by the date in A1. For some purposes, you may need to know what the last Friday of any given month is. This is easily determined with this formula:
=DATE(YEAR(A1),MONTH(A1)+1,0)-WEEKDAY(DATE (YEAR(A1),MONTH(A1)+1,0))+(WEEKDAY(DATE (YEAR(A1),MONTH(A1)+1,0))>5)*7-1
This formula calculates the last day of the month for the date in cell A1 and, based on what day of the week that date is, subtracts the appropriate number of days to return the previous Friday.
If you want to take business holidays into account, then the complexity of the formula gets quite high, quite quickly. Because of that, it is best to create a user-defined function (a macro) that will determine the last business day and compensate for holidays.
The following macro returns a date, Monday through Friday, that represents the last business day. The date is compared against a holiday list (HolidayList), which should be a named range in your workbook. If the date is found to be a holiday, then the ending business day is decremented until a suitable day is located.
Function LastWorkDay(lRawDate As Long, _ Optional rHolidayList As Range, _ Optional bFriday As Boolean = False) As Long LastWorkDay = DateSerial(Year(lRawDate), _ Month(lRawDate) + 1, 0) - 0 If bFriday Then LastWorkDay = MakeItFriday(LastWorkDay) Else LastWorkDay = NoWeekends(LastWorkDay) End If If Not rHolidayList Is Nothing Then Do Until myMatch(LastWorkDay, rHolidayList) = 0 LastWorkDay = LastWorkDay - 1 If bFriday Then LastWorkDay = MakeItFriday(LastWorkDay) Else LastWorkDay = NoWeekends(LastWorkDay) End If Loop End If End Function
Private Function myMatch(vValue, rng As Range) As Long myMatch = 0 On Error Resume Next myMatch = Application.WorksheetFunction _ .Match(vValue, rng, 0) On Error GoTo 0 End Function
Private Function NoWeekends(lLastDay As Long) As Long NoWeekends = lLastDay If Weekday(lLastDay) = vbSunday Then _ NoWeekends = NoWeekends - 2 If Weekday(lLastDay) = vbSaturday Then _ NoWeekends = NoWeekends - 1 End Function
Private Function MakeItFriday(lLastDay As Long) As Long MakeItFriday = lLastDay While Weekday(MakeItFriday) <> vbFriday MakeItFriday = MakeItFriday - 1 Wend End Function
Notice that there are three private functions that are included. These functions are called from within the main LastWorkDay function. The first one, myMatch, is a "wrapper" for the regular Match method. This usage is included because of the required error handling.
The second function, NoWeekdends, is used to back a date up to the previous Friday if it just happens to be a Saturday or Sunday. The MakeItFriday function is used to ensure that a date will always be a Friday.
To use this user-defined function from your worksheet, you use it in a formula, like this:
=LastWorkDay(A1, HolidayList, TRUE)
The first parameter (A1) is the date to be evaluated. The second parameter (HolidayList) is an optional list of holiday dates. As shown here, it is assumed that HolidayList is a named range in the worksheet. If this parameter is provided, then the function makes sure that any date it returns is not on the list of dates in HolidayList.
The final parameter is also optional; it can be either TRUE or FALSE. (The default, if it is not specified, is FALSE.) If this parameter is set to TRUE, then the function always returns the last Friday of the month. If this parameter is TRUE and the HolidayList is provided, then the function returns the last non-holiday Friday of the month.
Note:
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (2452) applies to Microsoft Excel 97, 2000, 2002, and 2003. You can find a version of this tip for the ribbon interface of Excel (Excel 2007 and later) here: The Last Business Day.
Program Successfully in Excel! John Walkenbach's name is synonymous with excellence in deciphering complex technical topics. With this comprehensive guide, "Mr. Spreadsheet" shows how to maximize your Excel experience using professional spreadsheet application development tips from his own personal bookshelf. Check out Excel 2013 Power Programming with VBA today!
Need to know what day of the year a certain date is? You can figure it out easily using the formulas in this tip.
Discover MoreConverting from one calendar system to another can be a challenge. The key is identifying the differences between the ...
Discover MoreExcel can easily store dates. If you want to increment a date by one month, there are a number of ways you can accomplish ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
2019-08-16 10:48:00
Douglas
Hi, your solution for bumping dates backwards if a date is a weekend is so elegant.
I wondered if you know a way of bumping dates forward using a similar approach.
I almost had it by taking:
> weekday(<>, 2)
> subtracting 5
> dividing 2 by the result
> taking max(0,<>)
but the problem is that friday results in division by 0 (ie weekday formula gives 5... -5 gives 0... 2/0 = division by 0)
Got a version of Excel that uses the menu interface (Excel 97, Excel 2000, Excel 2002, or Excel 2003)? This site is for you! If you use a later version of Excel, visit our ExcelTips site focusing on the ribbon interface.
FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
Copyright © 2024 Sharon Parq Associates, Inc.
Comments