Please Note: This article is written for users of the following Microsoft Excel versions: 2007, 2010, 2013, 2016, 2019, Excel in Microsoft 365, and 2021. 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: Calculating a Date Five Days before the First Business Day.
Written by Allen Wyatt (last updated December 17, 2022)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, Excel in Microsoft 365, and 2021
DeWayne has a date in cell A1, and it is easy to extract the month from that date. What he needs to do, however, is to calculate the date that is five calendar days before the first business day of the month. Thus, if the date in cell A1 is October 10, 2022, then the first business day of the month would be October 3 and five days before that would be September 28. (It is important to note that the five-day adjustment is based on calendar days, not on business days.)
There are many different formulas you can use to derive such a date. The shortest one that I've come across is this one:
=WORKDAY(A1-DAY(A1),1)-5
It subtracts the day of the month from the current date, which gives the last day of the previous month. Using this as a parameter for the WORKDAY function, along with a second parameter of 1, gives you the first workday (business day) of the current month. Five days is then subtracted from this date, giving the desired result.
You could also, if you prefer, use the EOMONTH function within the formula, in this manner:
=WORKDAY(EOMONTH(A1,-1),1)-5
The EOMONTH(A1,-1) portion of the formula gives the same result as A1-DAY(A1), which is the last day of the previous month.
You could also use the third parameter of the WORKDAY function to take holidays into account, if you desire. The easiest way to do this is in this manner:
=WORKDAY(A1-DAY(A1),1,MyHolidays)-5
In this usage, MyHolidays is a name you assign to a range of cells, where each cell contains the date of a holiday during the year.
It should be noted that the WORKDAY function assumes that the non-workdays are Saturday and Sunday. This might not always be the case, however. If you want the ability to specify different non-workdays, then you should investigate the WORKDAY.INTL function, which was introduced in Excel 2010. It works much the same as the WORKDAY function, except it adds a new parameter that is specified in the third position. For instance, let's say that DeWayne runs a barber shop that is closed on Sunday and Monday. (These are the non-business days for DeWayne's business.) In that case, you could calculate the date that is five days before the the first business day of the month with the following:
=WORKDAY.INTL(A1-DAY(A1),1,2,MyHolidays)-5
In this case, if the date in cell A1 is still October 10, 2022, then the first business day of the month would be October 1 (a Saturday, which is a business day for DeWayne's barber shop), and five days before that would be September 26.
Note the addition of the third parameter, in this case the value 2. This value indicates which days of the week are your non-workdays. The value can be one of the following:
Value | Non-Workdays | |
---|---|---|
1 | Saturday/Sunday | |
2 | Sunday/Monday | |
3 | Monday/Tuesday | |
4 | Tuesday/Wednesday | |
5 | Wednesday/Thursday | |
6 | Thursday/Friday | |
7 | Friday/Saturday | |
11 | Sunday | |
12 | Monday | |
13 | Tuesday | |
14 | Wednesday | |
15 | Thursday | |
16 | Friday | |
17 | Saturday |
Other than the added third parameter, the WORKDAY.INTL function works the same as the WORKDAY function.
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (12179) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, Excel in Microsoft 365, and 2021. You can find a version of this tip for the older menu interface of Excel here: Calculating a Date Five Days before the First 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!
Do you need to figure out the date for the first Tuesday of any given month? Excel is incredibly flexible when it comes ...
Discover MoreYou can use Excel to work with times and dates. Sometimes, however, figuring out the best way to do that can be tricky. ...
Discover MoreWhen you enter a date into a cell and you omit the year, Excel helpfully adds the current year to the date. If you want ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
There are currently no comments for this tip. (Be the first to leave your comment—just use the simple form above!)
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