Counting Month Ends

Written by Allen Wyatt (last updated July 18, 2023)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, 2021, and Excel in Microsoft 365


Kim has a worksheet into which she places a start date (column C) and an end date (column D). She needs a way to calculate the count of month ends between the two dates. For instance, if the start date is 1/1/17 and the end date is 7/31/17, the number of month ends is 7. If, however, the end date is 7/30/17, the number of month ends is 6.

There are any number of formulas you could devise to calculate the proper count. The simplest formula is if you can always count on the date in column C being the start of a month. In that case, the following formula will work just fine:

=DATEDIF(C1,D1+1,"m")

If you cannot count on column C containing a date that is the start of a month, but you can count on the beginning and ending dates always being in the same year, then any of the following formulas will do the trick:

=IF(MONTH(D1+1)=MONTH(D1),MONTH(D1)-MONTH(C1),MONTH(D1)-MONTH(C1)+1)
=IF(MONTH(D1+1)=MONTH(D1),MONTH(D1)-1,MONTH(D1))-MONTH(C1)+1
=MONTH(EOMONTH(D1,0))-MONTH(EOMONTH(C1,0))+(EOMONTH(D1,0)=D1)
=IF(EOMONTH(D1,0)=D1,MONTH(D1)-MONTH(C1)+1,MONTH(D1)-MONTH(C1))
=IF(D1<EOMONTH(D1,0),MONTH(D1)-1,MONTH(D1))-MONTH(C1)+1
=MONTH(D1)-MONTH(C1)+IF(D1=EOMONTH(D1,0),1,0)

If the years on the beginning and ending dates might be different, then the formulas are a bit more complex. Any of the following variations will calculate the correct number of month ends in the date range:

=12*(YEAR(D1)-YEAR(C1))+MONTH(D1)-MONTH(C1)+INT(D1=EOMONTH(D1,0))
=12*(YEAR(D1)-YEAR(C1))+MONTH(D1)-MONTH(C1)+IF(EOMONTH(D1,0)=D1,1,0)
=12*YEAR(D1)+MONTH(D1)-12*YEAR(C1)-MONTH(C1)+IF(D1=EOMONTH(D1,0),1,0)
=12*YEAR(D1)+MONTH(D1)-12*YEAR(C1)-MONTH(C1)+(D1=EOMONTH(D1,0))
=12*YEAR(D1)+MONTH(D1)-12*YEAR(C1)-MONTH(C1)+(DAY(D1+1)=1)
=MONTH(D1)+12*YEAR(D1)-MONTH(C1)-12*YEAR(C1)+IF(EOMONTH(D1,0)=D1,1,0)
=(MONTH(D1+1)+12*YEAR(D1+1))-(MONTH(C1)+12*YEAR(C1))
=IF(D1=EOMONTH(D1,0),1,0)+MONTH(D1)-MONTH(C1)+((YEAR(D1)-YEAR(C1))*12)
=IF(EOMONTH(D1,0)=D1,(MONTH(D1)-MONTH(C1)+1)+(YEAR(D1)-YEAR(C1))*12,MONTH(D1)-MONTH(C1)+(YEAR(D1)-YEAR(C1))*12)
=IF(D1=EOMONTH(D1,0),DATEDIF(EOMONTH(C1,-1),EOMONTH(D1,0),"m"),DATEDIF(EOMONTH(C1,-1),EOMONTH(D1,0),"m")-1)
=IF(D1<C1,"Error",MONTH(D1)-MONTH(C1)+IF(D1MONTH(D1+1))*1)
=IF(D1<C1,"Error",(YEAR(D1)-YEAR(C1))*12+(MONTH(D1)-MONTH(C1))+(EOMONTH(D1,0)=D1))
=SUM(N(FREQUENCY(EOMONTH(ROW(INDIRECT(C1&":"&D1)),0),EOMONTH(ROW(INDIRECT(C1&":"&D1)),0))>0))-(D1<EOMONTH(D1,0))

Some of these formulas are a bit long, so you'll want to carefully watch that you get them all if you choose to use one.

If you prefer to use a macro approach, then the following user-defined function may be of interest:

Function CountMonthEnds(sd As Date, ed As Date) As Integer
    Dim ceom As Integer
    Dim cmonth As Integer
    Dim lmonth As Integer
    Dim x As Date

    cmonth = 0
    ceom = 0
    cmonth = Month(sd)
    lmonth = cmonth
    ' go to end date + 1 to allow for end date being end of month
    For x = sd To ed + 1
        cmonth = Month(x)
        If cmonth <> lmonth Then
            ceom = ceom + 1
            lmonth = cmonth
        End If
    Next x
    CountMonthEnds = ceom
End Function

The macro simply steps through all the dates between the beginning and ending dates. It looks at the month for each of the dates, and if it changes, then it counts that as a "month end." This count is returned by the function.

ExcelTips is your source for cost-effective Microsoft Excel training. This tip (572) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, 2021, and Excel in Microsoft 365.

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

Automatic AutoCorrect Exceptions for Beginning Sentences

When automatically capitalizing the beginning of sentences, Word relies on how you historically have done your typing. ...

Discover More

Adding Pop-Up Documentation to a Cell

Want to have a small help screen pop up when a user selects a particular cell? This can be done by using data validation, ...

Discover More

Disappearing Status Bar

Ever had your Excel status bar disappear unexpectedly? Here's some ideas on why this may be happening.

Discover More

Program Successfully in Excel! This guide will provide you with all the information you need to automate any task in Excel and save time and effort. Learn how to extend Excel's functionality with VBA to create solutions not possible with the standard features. Includes latest information for Excel 2024 and Microsoft 365. Check out Mastering Excel VBA Programming today!

More ExcelTips (ribbon)

Calculating a Sum for a Range of Dates

If you use Excel to track information based on dates, you may wonder how to get a sum for only certain dates that you ...

Discover More

Calculating Dates for Thanksgiving

Ever wonder how to calculate the date for Thanksgiving in the United States? In this tip you discover not only that, but ...

Discover More

ISO Week Numbers in Excel

Work in an industry that uses ISO standards when it comes to working with dates? You'll love the formula in this tip ...

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 five minus 4?

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 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.