Please Note: This article is written for users of the following Microsoft Excel versions: 2007, 2010, and 2013. 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.

Calculating Months for Billing Purposes

by Allen Wyatt
(last updated October 11, 2014)

5

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, and 2013. You can find a version of this tip for the older menu interface of Excel here: Calculating Months for Billing Purposes.

Author Bio

Allen Wyatt

With more than 50 non-fiction books and numerous magazine articles to his credit, Allen Wyatt is an internationally recognized author. He  is president of Sharon Parq Associates, a computer and publishing services company. ...

MORE FROM ALLEN

Inserting the Document Revision Number

Need to know how many times your document has been saved? Word keeps track of this information, and makes it easily ...

Discover More

Using More CPU Power when Calculating

Today's PCs are more powerful than ever, but you can still have slowdowns when it comes to calculating large workbooks. ...

Discover More

Using Find and Replace

One of the basic editing tasks in any document is to find and replace information. Docs includes a basic tool that allows you ...

Discover More

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!

More ExcelTips (ribbon)

Determining Business Quarters from Dates

Many businesses organize information according to calendar quarters, especially when it comes to fiscal information. Given a ...

Discover More

Converting Coded Dates into Real Dates

Sometimes the format in which you receive data is not the same format that would be optimal for Excel. For instance, you ...

Discover More

Calculating Future Workdays

Need to calculate the date that is a certain number of workdays in the future? You can do so using a couple of different ...

Discover More
Subscribe

FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."

View most recent newsletter.

Comments

If you would like to add an image to your comment (not an avatar, but an image to help in making the point of your comment), include the characters [{fig}] in your comment text. You’ll be prompted to upload your image when you submit the comment. Images larger than 600px wide or 1000px tall will be reduced. Up to three images may be included in a comment. All images are subject to review. Commenting privileges may be curtailed if inappropriate images are posted.

What is three minus 2?

2014-10-21 06:03:20

yvan loranger

if anyone is interested:
my mistake was in assuming datedif counts only calendar months;
datedif("2014-9-9","2014-10-9","m") WILL return 1 month


2014-10-19 16:02:57

yvan loranger

if anyone is interested:
my mistake was in assuming datedif counts only calendar months;
datedif(x,y,"m") WILL return 1 month for x=sept9 y=oct9 [I'm taking liberty with syntax here]


2014-10-12 09:49:00

yvan loranger

oops i goofed

ignore my 11 oct 9:45 entry


2014-10-11 14:51:25

Michael (Micky) Avidan

@yvan loranger,
I didn't check your suggestion but from just looking at it - I have 2 comments:
1) DATEDIF(A1,A2),"m") is wrong.
The correct syntax is: DATEDIF(A1,A2,"m")
2) If you are concerned about shorter formulas - use:
=(NETWORKDAYS(A1,EOMONTH(A1,0))>=5)+(NETWORKDAYS(EOMONTH(A2,-1)+1,A2)>=5)+DATEDIF(A1,A2,"m")
Michael (Micky) Avidan
“Microsoft® Answers" - Wiki author & Forums Moderator
“Microsoft®” MVP – Excel (2009-2015)
ISRAEL


2014-10-11 09:45:38

yvan loranger

excellent; can be shortened to

=(NETWORKDAYS(A1, DATE(YEAR(A1), MONTH(A1) + 1,0), MyHolidays) >= 5)
+ (NETWORKDAYS(DATE(YEAR(A2), MONTH(A2),1), A2, MyHolidays) >= 5)
+ DATEDIF(A1,A2), "m")


This Site

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.

Newest Tips
Subscribe

FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."

(Your e-mail address is not shared with anyone, ever.)

View the most recent newsletter.