Please Note: This article is written for users of the following Microsoft Excel versions: 2007 and 2010. If you are using an earlier version (Excel 2003 or earlier), this tip may not work for you. For a version of this tip written specifically for earlier 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.
Note:
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (10085) applies to Microsoft Excel 2007 and 2010. You can find a version of this tip for the older menu interface of Excel here: The Last Business Day.
Professional Development Guidance! Four world-class developers offer start-to-finish guidance for building powerful, robust, and secure applications with Excel. The authors show how to consistently make the right design decisions and make the most of Excel's powerful features. Check out Professional Excel Development today!
Excel is great when it comes to working with dates and times. You can even do math on dates. One such easy manipulation ...
Discover MoreExcel works very well with dates and times. One thing you cannot do, however, is to create a custom format that displays ...
Discover MoreExcel makes it easy to import information created in other programs. Converting the imported data into something you can ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
2013-11-16 12:27:46
Brian
I wanted the last workday of the current month, so this is what I came up with..
=workday(eomonth(today(),0),-1,0)
The last 0 can de replaced with a range of holidays to eliminate them as well.
2013-09-26 12:24:04
Bryan
It wasn't intended as a criticism; I just assumed by the way you asked the question that you weren't familiar with Excel.
However, now I see what you are talking about. I think the problem is actually with the line returns, not the spaces. You can save a step by double-clicking in the target cell (or pressing F2 to enter cell edit mode) and pasting the formula there. Before pressing enter, you can delete the extra line returns.
You are correct about the formatting on formula 2. If you don't want to use cell formatting you could also wrap the whole formula in the TEXT formula.
2013-09-25 22:03:19
Tony
Thanks for the criticism Bryan and Martin. There are many people who come to me for advice on Excel, so my status is a bit different to what you've assumed.
Copying those two formulas and Pasting them does not work because they copy with spaces. I resolved this by pasting into Notepad, eliminating the spaces, then copying again and Pasting into Excel. The second formula actually gave a numerical result which had to be reformatted into a Date format.
2013-09-22 08:22:00
Martin Nicol
I am so impressed with this tip and the comments. I spent hours learning from this. For Tony and others learning: The EOM...,0)part just gives the last day of the month. The second Workday and ,1 asks for the workday following that last day of the month. The first Workday and the ,-1, ask for the workday before. Basically, the double workday function simply eliminates the weekend dates.
2013-09-22 07:45:35
Bryan
Tony, have you used Excel before? These formulas might be a little advanced otherwise; there are tons of good, free, basic tutorials around the internet.
That being said, to use the first two formulas, all you have to do is type a date into cell A1, and then pick any other cell and copy/paste the formula into it. It will tell you the last working date of the month in cell A1.
To use the macro code, hit Alt+F11 to open the VBA IDE, then Insert > Module. Paste the code into the dialogue that opens, then use the last formula in the article to find the last working date.
2013-09-21 17:45:54
Tony
How and where do I enter these formulas?
I'm completely lost.
2013-09-20 09:50:02
Chuck Trese
SmeesterH,
very clever, I love that.
even simpler:
Workday(Workday(EOMonth(A1,0),1),-1)
2012-10-06 09:33:43
SmeestersH
Workday(Workday(Date(Y,M+1,0),1),-1)
Got a version of Excel that uses the ribbon interface (Excel 2007 or later)? This site is for you! If you use an earlier version of Excel, visit our ExcelTips site focusing on the menu 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