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.

The Last Business Day

by Allen Wyatt
(last updated April 3, 2014)

9

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.

Author Bio

Allen Wyatt

With more than 50 non-fiction books and numerous magazine articles to his credit, Allen Wyatt is an internationally recognized author. He  is president of Sharon Parq Associates, a computer and publishing services company. ...

MORE FROM ALLEN

Speeding Up Document Display

Are your documents displaying too slowly? You can configure Word so that it is as quick as possible on displaying by using ...

Discover More

Selective Formatting using Find and Replace

The Find and Replace tool in Word allows you to search for formatting and alter it in your replacement text. What it doesn't ...

Discover More

Strip Trailing Spaces

If you get tired of documents that always seem to have extra spaces at the end of lines, here's a quick way to get rid of ...

Discover More

Solve Real Business Problems Master business modeling and analysis techniques with Excel and transform data into bottom-line results. This hands-on, scenario-focused guide shows you how to use the latest Excel tools to integrate data from multiple tables. Check out Microsoft Excel 2013 Data Analysis and Business Modeling today!

More ExcelTips (menu)

Calculating Months of Tenure

Need to know the number of months between two dates? It's easy to figure out if you use the DATEDIF function.

Discover More

Determining Month Names for a Range of Dates

Given a starting date and an ending date, you may want to generate the names of all the months between those two dates. This ...

Discover More

Alerts About Approaching Due Dates

You may use Excel to track due dates for a variety of purposes. As a due date approaches, you may want that fact drawn to ...

Discover More
Subscribe

FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."

View most recent newsletter.

Comments

If you would like to add an image to your comment (not an avatar, but an image to help in making the point of your comment), include the characters [{fig}] in your comment text. You’ll be prompted to upload your image when you submit the comment. Images larger than 600px wide or 1000px tall will be reduced. Up to three images may be included in a comment. All images are subject to review. Commenting privileges may be curtailed if inappropriate images are posted.

What is four less than 6?

2014-12-04 11:31:09

Michael (Micky) Avidan

Although there is no need for a UDF - if one wants to go this way - based on Tom's suggestion and while the cell has the full(!) date - I would use the following UDF:
------------------------------------
Public Function LastBusinessDay(d As Date)
d = Application.EoMonth(d, 0)
d = d - Choose(Weekday(d), 2, 0, 0, 0, 0, 0, 1)
LastBusinessDay = d
End Function
--------------
Michael (Micky) Avidan
“Microsoft® Answers" - Wiki author & Forums Moderator
“Microsoft®” MVP – Excel (2009-2015)
ISRAEL


2014-12-04 10:59:09

Michael (Micky) Avidan

Well, it seems as if the following formula is the shortest that provides the last working day in a given Month (by date):
=WORKDAY(EOMONTH(A1,0)+1,-1)
Michael (Micky) Avidan
“Microsoft® Answers" - Wiki author & Forums Moderator
“Microsoft®” MVP – Excel (2009-2015)
ISRAEL


2014-12-03 14:09:43

Tom Robinson

Here is my easy-to-understand VBA version:

' Calculate the last Mon-Fri business day of the month
Public Function LastBusinessDay(y As Long, m As Long) As Date
Dim d As Date
d = DateSerial(y, m + 1, 0) ' last day of month M is 0'th day of month M+1
If Weekday(d) = vbSunday Then d = d - 1 ' If Sunday, move back to Saturday
If Weekday(d) = vbSaturday Then d = d - 1 ' If Saturday, move back to Friday
LastBusinessDay = d
End Function

...Tom


2014-05-25 08:32:48

Michael (Micky) Avidan

...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


2014-05-25 08:23:52

Michael (Micky) Avidan

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


2014-05-23 19:39:38

DaveC

And thank you for that last workaround!

Dave


2014-05-23 19:38:08

DaveC

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


2014-05-23 18:49:41

awyatt

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.


2014-05-23 18:34:09

Dave

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


This Site

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.

Newest Tips
Subscribe

FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."

(Your e-mail address is not shared with anyone, ever.)

View the most recent newsletter.