Formula to calc YEARS, MONTHS, WEEKS and DAYS between two dates

srands

Board Regular
Joined
Jun 24, 2010
Messages
115
Hi I want a Formula to calc the number of:
YEARS, MONTHS, WEEKS and DAYS between two dates

I have tried the following:

DATEDIF (Does NOT calculate the number of WEEKS)
=DATEDIF(A1,A2,"y") & " Years, " & DATEDIF(A1,A2,"ym") & " Months, " & DATEDIF(A1,A2,"md") & " Days"

I realise there are formulas', that JUST calculate the number of WEEKS, such as:
=SUM(B151-B150)/7
OR
=INT((B151-B150)/7)


HENCE TO REITERATE 'A' FORMULA to calculate the number of:
YEARS, MONTHS, WEEKS and DAYS between two dates, would be great.

OR even better 'A' FORMULA to calc the number of:
YEARS, MONTHS, WEEKS, DAYS, HOURS, MINUTES and SECONDS between two dates and times (FORMAT CELLS, custom, dd/mm/yyyy hh:mm:ss) would be great.

Cheers

Stephan Rands<?xml:namespace prefix = o ns = "urn:schemas-microsoft-com:eek:ffice:eek:ffice" /><o:p></o:p>
<o:p> </o:p>
07772000679<o:p></o:p>
<o:p> </o:p>
mail@srands.co.uk<o:p></o:p>
<o:p> </o:p>
www.srands.co.uk<o:p></o:p>
 

Excel Facts

Copy PDF to Excel
Select data in PDF. Paste to Microsoft Word. Copy from Word and paste to Excel.
To get 'weeks' all you have to do is divide DAYS by 7 (use INT, ROUNDDOWN etc. to remove the decimal fraction). In a similar manner multiply by the appropriate manner to get HOURS, MINUTES etc.
Also, given that a date is held as a number with time being the decimal fraction you could always subtract one from the other and then perform your calculations on the result.
 
Upvote 0
I realise DAYS / 7 = WEEKS!

I have considered what you suggested about many separate calculations, that is impractical.

What I want is either 'A' FORMULA that calculates the:

i) YEARS, MONTHS, WEEKS and DAYS between two dates.

OR

ii) YEARS, MONTHS, WEEKS, DAYS, HOURS, MINUTES and SECONDS between two dates and times (FORMAT CELLS, custom, dd/mm/yyyy hh:mm:ss).
 
Upvote 0
David MrRitchie suggests this formula

=DATEDIF(B2,C2 -(MOD(B2,1)>MOD(C2,1)),"y")&" years, "&DATEDIF(B2,C2 -(MOD(B2,1)>MOD(C2,1)),"ym")&" months, "&DATEDIF(B2,C2 -(MOD(B2,1)>MOD(C2,1)),"md")&" days, "&TEXT(MOD(C2-B2,1),"hh "" hours, "" mm "" minutes, and "" ss ""seconds""")

see his website for more

That gives you everything but weeks. This revised version will give you weeks too (note: I removed the last MOD function in the above which isn't necessary)

=DATEDIF(B2,C2 -(MOD(B2,1)>MOD(C2,1)),"y")&" years, "&DATEDIF(B2,C2 -(MOD(B2,1)>MOD(C2,1)),"ym")&" months, "&INT(DATEDIF(B2,C2 -(MOD(B2,1)>MOD(C2,1)),"md")/7)&" weeks, "&MOD(DATEDIF(B2,C2 -(MOD(B2,1)>MOD(C2,1)),"md"),7)&" days, "&TEXT(C2-B2,"h"" hours, "" m"" minutes, and "" s"" seconds""")
 
Upvote 0
I used the modified formula that displays weeks but when I put in 8/1/12 to 9/30/12 it returns 1 month, 4 weeks, 1 days. I'm trying to figure out rental costs where we get reduced rates for months and weeks. The difference between these two dates should be: 2 months, 1 day. How do I get it to figure in this way?






David MrRitchie suggests this formula

=DATEDIF(B2,C2 -(MOD(B2,1)>MOD(C2,1)),"y")&" years, "&DATEDIF(B2,C2 -(MOD(B2,1)>MOD(C2,1)),"ym")&" months, "&DATEDIF(B2,C2 -(MOD(B2,1)>MOD(C2,1)),"md")&" days, "&TEXT(MOD(C2-B2,1),"hh "" hours, "" mm "" minutes, and "" ss ""seconds""")

see his website for more

That gives you everything but weeks. This revised version will give you weeks too (note: I removed the last MOD function in the above which isn't necessary)

=DATEDIF(B2,C2 -(MOD(B2,1)>MOD(C2,1)),"y")&" years, "&DATEDIF(B2,C2 -(MOD(B2,1)>MOD(C2,1)),"ym")&" months, "&INT(DATEDIF(B2,C2 -(MOD(B2,1)>MOD(C2,1)),"md")/7)&" weeks, "&MOD(DATEDIF(B2,C2 -(MOD(B2,1)>MOD(C2,1)),"md"),7)&" days, "&TEXT(C2-B2,"h"" hours, "" m"" minutes, and "" s"" seconds""")
 
Upvote 0
How do you get 2 months 1 day, even on the most generous side (from start of 8/1/12 to end of 9/30/12) that would only be 2 months, surely? Can you give some more examples of time periods and what result you would expect?
 
Upvote 0
I'm trying to create a budget for a rental car contracts.

I figure full days including the beginning and ending day of the contract. Essentially rental the morning of 8/1 and return the evening of 9/30

August (31 days) + September (30 days)=61 rental days.

So for my purposes I need it to display the difference between these dates as: 2 months (of 30 days) and 1 day remaining. If there is a way to do this I would love to be able to modify my "month" length as some vendors bill on a 28 day month.

I'm guessing my problem is to do with the way excel figures calendar months as opposed to actual days but I'm not sure.

Eventually I'd love to be able to plug in the monthly, weekly, and daily rates and have it spit out my total cost.




How do you get 2 months 1 day, even on the most generous side (from start of 8/1/12 to end of 9/30/12) that would only be 2 months, surely? Can you give some more examples of time periods and what result you would expect?
 
Upvote 0
OK, if you are counting 30 days as a month then try this version

=INT((B2-A2+1)/30)&" months "&MOD(B2-A2+1,30)&" days"
 
Upvote 0
Where is this DATEDIF function coming from? It's not a function in my version of Excel 2007 or in VBA yet, it seems to work.
 
Upvote 0
The Excel worksheet function DATEDIF is undocumented; however, if you Google search for excel datedif (make sure this is only one "f" in datedif when you type it) you will find several sites with "documentation". As for VBA, it has a DateDiff function (note the two "f"s), but it works completely differently from the worksheet function DATEDIF.

NOTE: Since you say you are using XL2007, you may find what I posted in my mini-blog article here to be of interest...
Recommendation: Do not use the undocumented DATEDIF function
 
Last edited:
Upvote 0

Forum statistics

Threads
1,213,489
Messages
6,113,952
Members
448,535
Latest member
alrossman

We've detected that you are using an adblocker.

We have a great community of people providing Excel help here, but the hosting costs are enormous. You can help keep this site running by allowing ads on MrExcel.com.
Allow Ads at MrExcel

Which adblocker are you using?

Disable AdBlock

Follow these easy steps to disable AdBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the icon in the browser’s toolbar.
2)Click on the "Pause on this site" option.
Go back

Disable AdBlock Plus

Follow these easy steps to disable AdBlock Plus

1)Click on the icon in the browser’s toolbar.
2)Click on the toggle to disable it for "mrexcel.com".
Go back

Disable uBlock Origin

Follow these easy steps to disable uBlock Origin

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back

Disable uBlock

Follow these easy steps to disable uBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back
Back
Top