Exceljet

Quick, clean, and to the point

Get days, months, and years between dates

Excel formula: Get days, months, and years between dates
Generic formula 
=DATEDIF(start,end,"y") &" years,"&DATEDIF(start,end,"ym") &" months," &DATEDIF(start,end,"md") &" days"
Explanation 

To calculate and display the time between dates in days, months, and years, you can use the a formula based on the DATEDIF function.

In the example shown, the formula in D6 is:

=DATEDIF(B6,C6,"y") &" years,"&DATEDIF(B6,C6,"ym") &" months," &DATEDIF(B6,C6,"md") &" days"

where start dates are in column B, and end dates are in column C.

How this formula works

The DATEDIF function is designed to calculate the difference between dates in years, months, and days. There are several variations available (e.g. time in months, time in months ignoring days and years, etc.) and these are set by the "unit" argument in the function. See this page on the DATEDIF function for a full list of available units.

In the example shown, we calculate years, months, and days separately, then "glue" the results together with concatenation. To get whole years, we use:

DATEDIF(B6,C6,"y")&" years,"

To get whole months, we use:

DATEDIF(B6,C6,"ym")&" months,"

And we calculate days with:

DATEDIF(B6,C6,"md")&" days"

The rest of the formula is simply the required text joined together with the concatenation operator (&).

Without zero values

To prevent the output of days, months, or years with zero values, you can wrap each DATEDIF function inside IF, as shown here (line breaks added for readability):

=
IF(DATEDIF(B6,C6,"y"), DATEDIF(B6,C6,"y")&"yr ","")&
IF(DATEDIF(B6,C6,"ym"), DATEDIF(B6,C6,"ym")&" mo ","")&
IF(DATEDIF(B6,C6,"md"), DATEDIF(B6,C6,"md") &" dy","")

To prevent extra commas from appearing in the final result, commas have been replaces by spaces. Using the original DATEDIF formula as the "logical test" inside IF works because IF treats any non-zero result as true.

Author 
Dave Bruns

Excel Formula Training

Formulas are the key to getting things done in Excel. In this accelerated training, you'll learn how to use formulas to manipulate text, work with dates and times, lookup values with VLOOKUP and INDEX & MATCH, count and sum with criteria, dynamically rank values, and create dynamic ranges. You'll also learn how to troubleshoot, trace errors, and fix problems. Instant access. See details here.