Counting Month Ends

by Allen Wyatt
(last updated February 19, 2021)

2

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, and 2016.

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

Incrementing References by Multiples when Copying Formulas

You can easily set up a formula to perform some calculation on a range of cells. When you copy that formula, the copied ...

Discover More

Splitting Cells by Case

Excel provides several different ways that you can split apart the contents of a cell. One way it doesn't provide is to ...

Discover More

Creating and Naming a Worksheet Using a Macro

You can use macros to make your common Excel tasks easier and faster. For instance, if you routinely need to create new ...

Discover More

Program Successfully in Excel! John Walkenbach's name is synonymous with excellence in deciphering complex technical topics. With this comprehensive guide, "Mr. Spreadsheet" shows how to maximize your Excel experience using professional spreadsheet application development tips from his own personal bookshelf. Check out Excel 2013 Power Programming with VBA today!

More ExcelTips (ribbon)

Month for the Nth Sunday

Doing math with dates is quite easy in Excel. As this tip illustrates, this fact makes it easy to figure out the Nth ...

Discover More

Parsing Non-Standard Date Formats

When you load data into Excel that was created in other programs, the formatting used for some types of data (such as ...

Discover More

Every Second Tuesday

Need a way to enter dates from every second Tuesday (or some other regular interval)? Excel makes it easy, providing ...

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. 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 two more than 3?

2021-02-22 17:02:24

robert Lohman

Your formula: =IF(D1<C1,"Error",MONTH(D1)-MONTH(C1)+IF(D1MONTH(D1+1))*1) has a major typo. Please correct for us.


2017-05-06 07:56:00

Alan Magner

how about the formula =MONTH(D2+1)-MONTH(C2)


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.