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: Calculating the First Business Day of the Month.
Written by Allen Wyatt (last updated May 25, 2024)
This tip applies to Excel 97, 2000, 2002, and 2003
Dan is setting up a worksheet for use in his company and needs a way to calculate the first business day of a calendar month. He knows how to calculate the first day of a month, but that day could possibly fall on a weekend or on a holiday.
There are several ways you can calculate the first weekday of a given month. The following formula is a good place to start:
=DATE(YEAR(A1),MONTH(A1),1)+CHOOSE(WEEKDAY(DATE(YEAR(A1),MONTH(A1),1)),1,0,0,0,0,0,2)
This formula assumes that you want the first weekday for the month of whatever date is in cell A1. Thus, if the date in cell A1 is 26 March 2011, the formula assumes you want the first weekday for March 2011.
If you have the Analysis ToolPak installed on your system, then the formula becomes much simpler:
=WORKDAY(EOMONTH(A1,-1), 1)
The EOMONTH function returns the last day of the month prior to the date in cell A1, and then the WORKDAY function returns the first weekday in the following month. The function is put together like this (using EOMONTH) because WORKDAY is a bit quirky; it assumes that the first parameter is a valid work day. This means that it doesn't check whether the date used in the parameter falls in the Monday through Friday work week. By forcing the parameter to be a day before the month in which you want to determine the first work day and setting the second parameter to 1, the function returns the first actual weekday for the desired month.
The WORKDAY function also allows you to optionally specify that holidays should be taken into account. The easiest way to do this is to set up a list of holiday dates, in a cell range, and then name that range. (How you name a range is discussed in other issues of ExcelTips.) If you give the range a name such as MyHolidays, then you can use the following version of the formula:
=WORKDAY(EOMONTH(A1,-1), 1, MyHolidays)
Here's a neat trick if you want to calculate the beginning work day for any given month in a year. Assume that cell A1 contains a year, such as 2011, and that cell A2 contains a month number, 1 through 12, representing the month for which you want the beginning work day. You can then use this formula to get the desired date:
=WORKDAY(DATE(A1,1,0), A2, MyHolidays)
The way the DATE function is used in this formula returns the last day of the year prior to the year specified in cell A1. Then the value in A2 is used to move forward that number of months, and MyHolidays (as before) accounts for any holidays that may occur in that month.
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (10199) 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 the First Business Day of the Month.
Comprehensive VBA Guide Visual Basic for Applications (VBA) is the language used for writing macros in all Office programs. This complete guide shows both professionals and novices how to master VBA in order to customize the entire Office suite for their needs. Check out Mastering VBA for Office 2010 today!
Do you look forward to the weekend? Well, you can use Excel to let you know when the next weekend begins. Here's how you ...
Discover MoreSometimes the format in which you receive data is not the same format that would be optimal for Excel. For instance, you ...
Discover MoreNeed to know the number of months between two dates? It's easy to figure out if you use the DATEDIF function.
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 © 2024 Sharon Parq Associates, Inc.
Comments