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 October 28, 2017)

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:


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:


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)
        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)
                LastWorkDay = NoWeekends(LastWorkDay)
            End If
    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
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. ...


Avoiding Rounding Errors in Formula Results

Some formulas just don't give the results you expect. Sometimes this is due to the way that Excel handles rounding. ...

Discover More

Searching for Multi-Byte Hex Codes

Need to find a character for which you only know the hex code? There are a few ways you can search for the information, ...

Discover More

Determining the Upper Bounds of an Array

When working with variables in a macro, you may need to know the upper boundary dimension for an array. This can be ...

Discover More

Save Time and Supercharge Excel! Automate virtually any routine task and save yourself hours, days, maybe even weeks. Then, learn how to make Excel do things you thought were simply impossible! Mastering advanced Excel macros has never been easier. Check out Excel 2010 VBA and Macros today!

More ExcelTips (menu)

Converting Between Buddhist and Gregorian Calendar Systems

Converting from one calendar system to another can be a challenge. The key is identifying the differences between the ...

Discover More

Calculating a Group Retirement Date

Calculating a retirement date can be as simple as doing some date math to see when a person reaches a certain age. ...

Discover More

Calculating the First Business Day of the Month

Want to know which day of the month is the first business day? There are a few ways you can check to make sure the date ...

Discover More

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

View most recent newsletter.


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. Maximum image size is 6Mpixels. 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 five more than 3?

There are currently no comments for this tip. (Be the first to leave your comment—just use the simple form above!)

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

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.