Loading
Excel.Tips.Net ExcelTips (Menu Interface)

The Last Business Day

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.

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.

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.

Related Tips:

Save Time! ExcelTips has been published weekly since late 1998. Past issues of ExcelTips are available in convenient ExcelTips archives. Have your own enhanced archive of ExcelTips at your fingertips, available to use at any time! Check out ExcelTips Archives today!

 

Comments for this tip:

Michael (Micky) Avidan    25 May 2014, 08:32
...and by the way - I checked your first proposed formula for the: 26/12/2013 (dd/mm/yyyy) - and I got: 31/12/2013 which is a Tuesday.
It should return: 27/12/2013 which was the last Friday in Dec. 2013.

Michael (Micky) Avidan
“Microsoft® Answers" - Wiki author & Forums Moderator
“Microsoft®” MVP – Excel (2009-2014)
ISRAEL
Michael (Micky) Avidan    25 May 2014, 08:23
The formula can be much simpler.
In order to return the last Friday's date for a given month determined from a date in Cell A1:
=EOMONTH(A1,0)-CHOOSE(WEEKDAY(EOMONTH(A1,0)),2,3,4,5,6,0,1)
In order for the EOMONTH to be available - one must enable the Analysis Toolpak (via Tools > add-on)
That EOMONTH became a build-in function in the newer versions of Excel.
Michael (Micky) Avidan
“Microsoft® Answers" - Wiki author & Forums Moderator
“Microsoft®” MVP – Excel (2009-2014)
ISRAEL

DaveC    23 May 2014, 19:39
And thank you for that last workaround!

Dave
DaveC    23 May 2014, 19:38
Sorry about that last comment, figured it out. What I'm really trying to accomplish is use this macro and add an additional macro which would essentially pop out the last working day of the previous week checked against the holiday list. Tried reworking your code here and was unsuccessful, any advice would be appreciated
awyatt    23 May 2014, 18:49
Dave: I believe that you can do it by changing this:

   Month(lRawDate) + 1

to this:

   Month(lRawDate) - 1

I haven't tested it though, so you'll want to do that.
Dave    23 May 2014, 18:34
The macro actually returns the last friday of whatever month you specify. How would one fix that and have it automatically calculate the prior month's last working day?

Regards,
Dave

Leave your own comment:

*Name:
Email:
  Notify me about new comments ONLY FOR THIS TIP
Notify me about new comments ANYWHERE ON THIS SITE
Hide my email address
*Text:
*What is 3+4? (To prevent automated submissions and spam.)
 
          Commenting Terms
 
 

Our Company

Sharon Parq Associates, Inc.

About Tips.Net

Contact Us

 

Advertise with Us

Our Privacy Policy

Our Sites

Tips.Net

Beauty and Style

Cars

Cleaning

Cooking

DriveTips (Google Drive)

ExcelTips (Excel 97–2003)

ExcelTips (Excel 2007–2013)

Gardening

Health

Home Improvement

Money and Finances

Organizing

Pests and Bugs

Pets and Animals

WindowsTips (Microsoft Windows)

WordTips (Word 97–2003)

WordTips (Word 2007–2013)

Our Products

Premium Newsletters

Helpful E-books

Newsletter Archives

 

Excel Products

Word Products

Our Authors

Author Index

Write for Tips.Net

Copyright © 2014 Sharon Parq Associates, Inc.