Written by Allen Wyatt (last updated December 1, 2018)
This tip applies to Excel 97, 2000, 2002, and 2003
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 September 26, 2012, then the first business day of the month would be September 3 and five days before that would be August 29.
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 two functions used so far (WORKDAY and EOMONTH) are both part of the Analysis ToolPak, which must be installed and enabled on your system in order for the functions to work. (How you enable the ToolPak is covered in other issues of ExcelTips.)
If you don't want to use the Analysis ToolPak for some reason, you can use a different formulaic approach, such as the following:
=A1-DAY(A1)+1+(WEEKDAY(A1-DAY(A1))=7)+2*(WEEKDAY(A1-DAY(A1))=6)-5
The formula calculates the first day of the month and then adds appropriate values based on whether the first day of the month is a Saturday or Sunday. Then, five days are subtracted from the result.
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (12178) 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: 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!
If your company closes out its accounting months at the end of each calendar quarter, figuring out the proper closing ...
Discover MoreExcel can easily store dates. If you want to increment a date by one month, there are a number of ways you can accomplish ...
Discover MoreMany businesses need to know when the last business day of the month occurs. This tip discusses several ways you can ...
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 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.
FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
Copyright © 2025 Sharon Parq Associates, Inc.
Comments