Including Weeks in Elapsed Time

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


3

Sally needs a formula that will return the number of years, months, weeks, and days that have elapsed since a beginning date. She's been able to find a formula that shows years, months, and days, but the inclusion of weeks is something that has eluded her for some time.

If Sally needed to only find the number of days or weeks or months or years between two dates, the math is rather simple. (Just calculate the number of days and divide by the appropriate average number of days in the week, month, or year.) That is not what she wants, however. She wants to know an answer that shows the number of elapsed years, months, weeks, and days between two dates.

Thus, if the starting date was June 10, 1966, and the ending date was February 5, 2019, then the answer she seeks would be "52 years, 7 months, 3 weeks, and 5 days." If the ending date is changed to February 7, 2019, then the answer would be "52 years, 7 months, 4 weeks, and 0 days." In this answer, each progressively granular date gradation functions only on the remainder of the preceding parts of the answer.

The formula to which Sally refers—which does not include an indicator for weeks—can be found at this page on the ExcelTips site:

https://excelribbon.tips.net/T011360

That tip shows several different formulas to arrive at a desired result, most relying on the DATEDIF function. (It doesn't make sense to recreate, on this page, the extensive information provided on the other ExcelTips page. You may want to go take a look at it, however.)

If adding weeks into the mix, the basic idea is to simply use the same DATEDIF approach, show the number of weeks, and adjust the number of days to take those weeks into account, in this manner:

=DATEDIF(A1,B1,"y") & " years, " & DATEDIF(A1,B1,"ym")
& " months, " & INT(DATEDIF(A1,B1,"md")/7) & " weeks, "
& MOD(DATEDIF(A1,B1,"md"),7) & " days"

This is essentially a modified version of the first full DATEDIF formula on the other ExcelTips page, referenced above. It doesn't take grammar and punctuation into account (as do the later formulas on the page), but it provides the desired information. It is a relatively simple extension of this base formula to get the grammar and punctuation correct.

This formula relies on A1 containing the starting date and B1 containing the ending date (the ending date could easily be set to today's date).

ExcelTips is your source for cost-effective Microsoft Excel training. This tip (12947) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, 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

Hyphenating Your Document

One of the final touches you can add to a document is to hyphenate it. This allows text to flow more smoothly from line ...

Discover More

ExcelTips: Powerful Lookup Functions (Special Offer)

ExcelTips: Powerful Lookup Functions is a key resource in discovering how to use Excel's amazing lookup functions. ...

Discover More

Read-Only Files

Read-only documents (those that cannot be updated) are part and parcel of working with Word. There are many ways that a ...

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)

Converting European Dates to US Dates

Those in Europe use a date format that is different than those in the US; this is not news. But what if you need to ...

Discover More

Forcing Dates Forward

Want to push a date to some pre-defined day of the month? Here are some ways to force the issue.

Discover More

Calculating Differences in Months using Non-Standard Date Values

Dates can be entered into a worksheet in any number of unique or novel ways. Working with those dates can be a challenge, ...

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

2023-11-13 11:23:17

Barry

Many thanks J Woolly for the code below. Mine was presumably way too simple to cope with all the variations. I shall study the code and try to learn from it (as usual). My coding is all just hobby stuff so I really do appreciate the effort and kindness others go to to help me. Your name is familiar to me, so I've obviously used your coding sometime previous. Thanks again


2023-11-03 15:46:42

J. Woolley

@Barry
You might be interested in the TimeDif function in My Excel Toolbox:
=TimeDif(Start, Finish, [Approximate], [Conversational])
Start and Finish must be numeric or text dates and/or times. TimeDif returns the difference between Start and Finish as text, which can optionally be exact, approximate, or conversational.
See https://sites.google.com/view/MyExcelToolbox/
Here is a modified conversational version of TimeDif returning years, months, weeks, and days only (ignoring hours, minutes, and seconds) in the style of your function:

Function elapsInclWeeks2(Start As Date, Finish As Date) As String
    Dim dS As Date, dF As Date, dDif As Double, e As String
    Dim y As Long, m As Long, d As Long, w As Long
    Dim y1 As Long, m1 As Long, d1 As Long
    Dim y2 As Long, m2 As Long, d2 As Long
    dDif = Finish - Start
    d = Int(dDif): dS = Int(Start): dF = Int(Finish)
    'check if finish time-of-day is less than start time-of-day
    If (Finish - dF) < (Start - dS) Then dF = dF - 1
    d1 = Day(dS)
    d2 = Day(dF)
    m1 = Month(dS)
    m2 = Month(dF)
    y1 = Year(dS)
    y2 = Year(dF)
    If d2 < d1 Then 'finish day is less than start day
        m2 = m2 - 1
        If m2 = 0 Then m2 = 12: y2 = y2 - 1
        'add previous month's days
        d2 = d2 + Day(DateSerial(y2, (m2 + 1), 0))
    End If
    If d > d2 - d1 Then d = d2 - d1
    w = d \ 7
    d = d Mod 7
    If m2 < m1 Then 'finish month is less than start month
        y2 = y2 - 1
        'add previous year's months
        m2 = m2 + 12
    End If
    m = m2 - m1
    y = y2 - y1
    Dim s(True To False) As String: s(True) = "": s(False) = "s"
    If y Then e = y & " year" & s(y = 1)
    If m Then e = e & IIf(y, ", ", "") & m & " month" & s(m = 1)
    If w Then e = e & IIf(y Or m, ", ", "") & w & " week" & s(w = 1)
    If d Then e = e & IIf(y Or m Or w, ", ", "") & d & " day" & s(d = 1)
    If e = "" Then e = "0 days"
    elapsInclWeeks2 = e
End Function

With some of your dates, for example:
20-Jan-2007 to 08-Feb-2024, "17 years, 2 weeks, 5 days"
20-Jan-2007 to 30-Jan-2024, "17 years, 1 week, 3 days"
20-Jan-2007 to 27-Jan-2024, "17 years, 1 week"
01-Jan-2000 to 01-Oct-2000, "9 months"
01-Jan-2000 to 08-Oct-2000, "9 months, 1 week"
01-Jan-2000 to 31-Oct-2000, "9 months, 4 weeks, 2 days"


2023-11-02 05:57:48

Barry

Including Weeks in Elapsed Time

In the earlier tip (T011360), Willy Vanhaelen added a VBA function to do the job for the Elapsed Time formula (for Y,M,D). That was helpful but resulting output was sometimes ‘weird’ as it produced negative portions as in:
Date1 = 20/01/2007; Date2 = 08/02/2024; Result =17 years, 1 month, -12 days.
I have tried to modify this AND include weeks in the result. However the output is still offering some ‘silly’ results:

Function elapsInclWeeks(a As Date, b As Date) As String
'Origin: Excel.Tips T011360 (Alan Wyatt)
'orig function: -- comments in above by Willy Vanhaelen--2016-06-10
Dim d As Integer, w As Integer, m As Integer, y As Integer
Dim s As String
Dim Mflag As Boolean: Mflag = False 'used to correct month value
Dim Yflag As Boolean: Yflag = False 'used to correct year value
'correction for negative output
If DatePart("d", b) <= DatePart("d", a) Then Mflag = True
If DatePart("m", b) = DatePart("m", a) Then Yflag = True
'calc years difference
y = DateDiff("yyyy", a, b)
If Yflag Then y = y - 1
'update value of a so that years match
a = DateAdd("yyyy", y, a)
'calc months difference
m = DateDiff("m", a, b)
If Mflag Then m = m - 1
'update value of a so that months match
a = DateAdd("m", m, a)
'calc weeks difference
w = Int(DateDiff("d", a, b) / 7)
'calc days difference
d = DateDiff("d", a, b) Mod 7
End Function

This ‘almost’ works but for the ‘silly’ output as in:
Date1 = 20/01/2007; Date2 = 30/01/2024; Result = 16 years, 12 months, 1 week, 3 days
Where the original formula* correctly gives: 17 years, 0 months, 1 week, 3 days
I have juggled but cannot spot the ‘error’

Also with start/end dates of:
Date1 = 01/01/2000; Date2 = 01/10/2000;
Function gives: 8 months, 4 weeks, 2 days.
Formula* gives: 9 months
Is this due to the way DateDiff() chops up the year depending on days in the month?

*the formula:
=DATEDIF($A$1,$B$1,"y") & " year(s), " & DATEDIF($A$1,$B$1,"ym")& " month(s), " & INT(DATEDIF($A$1,$B$1,"md")/7) & " week(s), "& MOD(DATEDIF($A$1,$B$1,"md"),7) & " day(s}."


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.