Please Note: This article is written for users of the following Microsoft Excel versions: 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365. 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 Months for Billing Purposes.
Written by Allen Wyatt (last updated July 11, 2020)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365
Olga keeps the books for a private school. For each student enrolled, she has an entry date and a drop date. She needs to figure out how many months to bill each student. If the student was in class for at least five days, that month should be included in the billing. If less than five days, they are not billed for that month. She also needs to exclude holidays and weekends.
Integral to any solution to this problem is going to be the use of the NETWORKDAYS function. This function, as described in other ExcelTips, calculates the net number of work days between two dates. It takes into account weekends and, optionally, holidays.
So, assuming you have the student's entry date in A1 and the drop date in A2, the only thing you need to do is set up a list of holidays. You can do that by simply starting to enter the holidays in a range of cells. Enter one date per cell, and then select the range. Define a name to refer to the range, such as MyHolidays.
You can then use a formula such as the following:
=(NETWORKDAYS(A1, DATE(YEAR(A1), MONTH(A1) + 1,0), MyHolidays) >= 5) + (NETWORKDAYS(DATE(YEAR(A2), MONTH(A2),1), A2, MyHolidays) >= 5) + DATEDIF(DATE(YEAR(A1), MONTH(A1) + 1, 1), DATE(YEAR(A2), MONTH(A2), 1), "m")
The formula is quite long and bears some examination. Note that besides the NETWORKDAYS function, it also uses the DATEDIF function, which is used to determine the difference between two dates and return the interval in different ways. In this instance, it is used with the "m" parameter, which means it returns the interval as a number of months—exactly what is needed by Olga.
The first part of the formula (the first use of the NETWORKDAYS function) is used to determine how many days there are between the entry date (in cell A1) and the end of the month in which the entry date occurs. If this value is greater than or equal to 5 (Olga's cutoff), then the value 1 is returned, since this counts as a single billable month.
The next part of the formula (the second use of the NETWORKDAYS function) is used to determine whether there are at least five class days in the month in which the drop date occurs. If so, then the value 1 is returned, again because this is a billable month.
The DATEDIF function is then used to return the number of full months between the entry month and the drop month. What you end up with is a count of the number of months that should be billed for the student.
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (9514) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365. You can find a version of this tip for the older menu interface of Excel here: Calculating Months for Billing Purposes.
Excel Smarts for Beginners! Featuring the friendly and trusted For Dummies style, this popular guide shows beginners how to get up and running with Excel while also helping more experienced users get comfortable with the newest features. Check out Excel 2013 For Dummies today!
Given a starting date and an ending date, you may want to generate the names of all the months between those two dates. ...
Discover MoreWant to find out how many of a particular weekday occurs within a given month? Here's how you can find the desired ...
Discover MoreDoing math with dates is easy in Excel. Doing math with old dates, such as those you routinely encounter in genealogy, is ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
2020-09-02 07:05:05
Richard Curtis
I have a question arising from the formula:
The first use of the NETWORKDAYS function compares the entry date A1 with the following month (MONTH(A1)+1) and zero is used for the day. I see from the DATE function help that this is a way of getting the last day of the current month. It might help if you could mention this in the article.
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