Calculating Differences in Months using Non-Standard Date Values

by Allen Wyatt
(last updated December 12, 2015)

5

Ian needs to enter the chronological age of a pupil in the first column, in the format 9.11 for nine years and eleven months, the reading age in the next column (say, 10.6 for ten years and six months), then calculate the difference in months in the third column, which in this case would be 7. The difference always needs to be shown in months, so it should show a gap as 14 months instead of 1.2 or 24 months instead of 2.0. Ian's at a loss as to how to put together such a formula.

The trick is to simply convert to a common set of units, in this case months. So, for instance, 10.6 would be 12*10+6, or 126 months. If you do this type of conversion to both the chronological age and the reading age, then you can do whatever subtraction you need in order to determine the difference, again in months.

There is a big, big caveat here, however: How you enter your non-standard dates into the worksheet is going to have a huge bearing on how you work with that data. The problem is best illustrated by considering a date value such as 10.10, meaning an age of 10 years and 10 months. If you enter this value directly into a cell, Excel will parse it as a numeric value and change it, automatically, to 10.1 because the trailing 0 is (to Excel) insignificant. Unfortunately, this value is indistinguishable from 10.1, meaning 10 years and 1 month.

There are two possible solutions. If you want to enter numeric values, then you should make sure you always include a leading 0 for the months. Thus, you would enter 10.01 or 10.06, not 10.1 or 10.6.

In Ian's problem statement, however, he specifically uses 10.6 as an example, which means that leading zeros are not being entered. In this case, you must make sure that what you are entering is parsed as text by Excel. In other words, make sure you format those date-entry columns as text before you start entering the dates. In that way, Excel will show 10.10 as just that, with the trailing zero.

All of the solutions you use to do the calculations assume that you are entering dates with the leading zero for months or that you are entering the dates as text values. In all instances, let's assume that the chronological ages are in column A and the reading ages are in column B. If your dates are formatted as text, you can then use a formula such as the following in column C:

=(INT(B1)*12+VALUE(RIGHT(B1,LEN(B1)-FIND(".",B1))))-
(INT(A1)*12+VALUE(RIGHT(A1,LEN(A1)-FIND(".",A1))))

Remember: This is a single formula, even though it shows here on two lines. It returns a positive value if the reading age is greater than the chronological age, or a negative value if the reading age is less than the chronological age. You can't use the formula if the dates are entered as numeric values because if the age is entered as 10.00 (meaning 10 years and 0 months), Excel still parses that value as 10. The formula then returns a #VALUE! error because the FIND function cannot locate a non-existant decimal point.

If you are using numeric-formatted dates (again, with leading zeros for months) then you can rely on either of these two formulas:

=12*(INT(A1)-INT(B1))+100*(MOD(A1,1)-MOD(B1,1))
=(DOLLARDE(A1,12)-DOLLARDE(B1,12))*12

The key is to be consistent in how your date values are formatted, use leading zeros for months if entering in numeric format, and use the proper formula based on whether you are working with text or numeric values.

ExcelTips is your source for cost-effective Microsoft Excel training. This tip (10095) 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

Setting the Distance between Text and Borders

Add a border around a piece of text (such as a paragraph), and Word makes some assumptions about the placement of that border ...

Discover More

Selecting a Suggestion with the Keyboard

Excel tries to anticipate what you want to type into a cell, particularly when it comes to entering formulas. Here are the ...

Discover More

Using the Status Bar

When developing a macro, you may want to display on the status bar what the macro is doing. Here's how to use this important ...

Discover More

Comprehensive VBA Guide Visual Basic for Applications (VBA) is the language used for writing macros in all Office programs. This complete guide shows both professionals and novices how to master VBA in order to customize the entire Office suite for their needs. Check out Mastering VBA for Office 2010 today!

More ExcelTips (ribbon)

Unique Military Date Format

Some industries (such as the military) have special formatting that they use to represent dates. Here is one such format and ...

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

Discover More

Calculating a Group Retirement Date

Calculating a retirement date can be as simple as doing some date math to see when a person reaches a certain age. ...

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 8Mpixels. 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 6 - 4?

2015-12-15 05:49:31

Michael (Micky) Avidan

@Scott Renz,
Check out the 'Num_Chars' argument used in the MID function.
Try: 1
Try: 256
I'm sure you got the point now.
-------------------------
Michael (Micky) Avidan
“Microsoft®” MVP – Excel (2009-2016)
ISRAEL


2015-12-14 11:26:14

Scott Renz

Hi Micky,
How does it determine if a numeric entry was "10.1" or "10.10"?


2015-12-13 06:57:44

Michael (Micky) Avidan

@Allen
here is a formula that handles ALL(!) possibilities (Integer Numerics, Decimal Numerics, Text etc):
=IF(MOD(B1-A1,1),INT(B1)*12+MID(B1,FIND(".",B1)+1,2)-(INT(A1)*12+MID(A1,FIND(".",A1)+1,2)),B1-A1)
-------------------------
Michael (Micky) Avidan
“Microsoft®” MVP – Excel (2009-2016)
ISRAEL


2015-12-12 16:52:27

Allen

Michael: Almost, but not quite. It doesn't work in all instances of numeric values.

For instance, if someone puts 10.00 in a cell, Excel parses it as 10. There is no decimal point to "find," so the formula produces a #VALUE! error. This is the same problem mentioned in my paragraph that starts with "Remember," above.

In instances of text-formatted values, it does work fine, and I should have included it. (It is shorter than the one I show.)

Thanks.

-Allen


2015-12-12 15:13:57

Michael (Micky) Avidan

@Allen,
To my opinion, my proposed formula (not being mentioned in your tip) is the shortest that handles both situations:
9.2 - 10.6
OR:
9.02 - 10.06
So, Here it is again:
=INT(B1)*12+MID(B1,FIND(".",B1)+1,2)-(INT(A1)*12+MID(A1,FIND(".",A1)+1,2))
-------------------------
Michael (Micky) Avidan
“Microsoft®” MVP – Excel (2009-2016)
ISRAEL


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.