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 Months for Billing Purposes.

Calculating Months for Billing Purposes

Written by Allen Wyatt (last updated October 22, 2022)
This tip applies to Excel 97, 2000, 2002, and 2003


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, is part of the Analysis ToolPak. Assuming you have the ToolPak enabled, the function will calculate 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 (3271) 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 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

Converting Endnotes to Regular Text

If you have a document with lots of endnotes, you may need them converted to regular text so that they can be used ...

Discover More

Protecting Custom Shortcut Keys

If you spend time creating a rich set of custom shortcut keys, it can be rather frustrating if they suddenly disappear. ...

Discover More

Entering a Degree Sign

One of the more common symbols that people need to use in their writing is the degree symbol, typically used after a ...

Discover More

Solve Real Business Problems Master business modeling and analysis techniques with Excel and transform data into bottom-line results. This hands-on, scenario-focused guide shows you how to use the latest Excel tools to integrate data from multiple tables. Check out Microsoft Excel 2013 Data Analysis and Business Modeling today!

More ExcelTips (menu)

Monthly Close-Out Dates

If your company closes out its accounting months at the end of each calendar quarter, figuring out the proper closing ...

Discover More

Calculating an Age On a Given Date

Start putting dates in a worksheet (especially birthdates), and sooner or later you will need to calculate an age based ...

Discover More

Determining Month Names for a Range of Dates

Given a starting date and an ending date, you may want to generate the names of all the months between those two dates. ...

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}] (all 7 characters, in the sequence shown) in your comment text. You’ll be prompted to upload your image when you submit the comment. Maximum image size is 6Mpixels. 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 8 + 7?

There are currently no comments for this tip. (Be the first to leave your comment—just use the simple form above!)


This Site

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.

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.