Skip to main content
cancel
Showing results for 
Search instead for 
Did you mean: 

Register now to learn Fabric in free live sessions led by the best Microsoft experts. From Apr 16 to May 9, in English and Spanish.

Reply
DataVitalizer
Super User
Super User

Calculating the difference between two dates in Years, Months, and Days

Hi Community,

I am working on a report where I have to calculate the difference between two dates (a specific date, and today) then show the resulat in the following format 00years - 00months - 00days

 

Example:

Date1 - Today()

Date2 - 08/19/2020

Result to show => 1 year, 9 months and 19 days

 

Currently I am using the DATEDIF function inside Excel then importing the result in my Power BI report, but everyday I have to open the exel file in order to get the new update then refresh my report in Power BI.

 

Please is there any DAX fomula that can show the date difference in the above format.

 

Thanks.

Best regards. 

 

1 ACCEPTED SOLUTION

@DataVitalizer Oh !! Ok, please try this (Just added two more conditions in the SWITCH statement)

 

Hopefully, this should fix all your test cases 🙂 Fingers Crossed !!

 

Final = 
VAR _Years = FLOOR(YEARFRAC([Date1],[Date2],4),1)
VAR _Months = FLOOR(MOD(YEARFRAC([Date1],[Date2],4),1) * 12.0,1)
VAR _daysinMonth = DAY(EOMONTH([Date1],0))
VAR _days = IF(DAY([Date1])<DAY([Date2]),DAY([Date2])-DAY([Date1]),DAY([Date2])+(_daysinMonth-DAY([Date1])))
VAR _daysFinal =  SWITCH(TRUE(),DAY(EOMONTH([Date1],0)) = _days || DAY(EOMONTH([Date2],0)) = _days,0,_days)

RETURN SWITCH(TRUE(),
             _Years>0 && _Months = 0 && _daysFinal = 0,_Years & " year(s)",
             _Years>0 && _Months>0 && _daysFinal = 0, _Years & " year(s), " & _Months & " month(s) ",
             _Years>0 && _Months >0 && _daysFinal >0, _Years & " year(s), " & _Months & " month(s) " & _daysFinal & " day(s)",
             _Years>0 && _Months = 0 && _daysFinal >0, _Years & " year(s), " & _daysFinal & " day(s)",
             _Months>0 && _daysFinal = 0, _Months & " month(s) ",
             _Months>0 && _daysFinal >0, _Months & " month(s) " & _daysFinal & " day(s)",
             _daysFinal & " day(s)"
             )

image.png





Did I answer your question? Mark my post as a solution!

Proud to be a PBI Community Champion




View solution in original post

16 REPLIES 16
Greg_Deckler
Super User
Super User

This measure will do it for that case, might need some testing for other use cases:

 

Note, for this measure, I created a Date1=TODAY() measure and a Date2=DATE(2020,8,19) measure.

 

Measure 4 = 
VAR __daysinMonth = DAY(EOMONTH([Date1],0))
VAR __years = DATEDIFF([Date1],[Date2],YEAR) - 1
VAR __months = IF(MONTH([Date1])<MONTH([Date2]),MONTH([Date2])-MONTH([Date1]),12-MONTH([Date1])+MONTH([Date2])-1)
VAR __days = IF(DAY([Date1])<DAY([Date2]),DAY([Date2])-DAY([Date1]),DAY([Date2])+(__daysinMonth-DAY([Date1])))
RETURN __years & " year, " & __months & " months and " & __days & " days"

@ me in replies or I'll lose your thread!!!
Instead of a Kudo, please vote for this idea
Become an expert!: Enterprise DNA
External Tools: MSHGQM
YouTube Channel!: Microsoft Hates Greg
Latest book!:
The Definitive Guide to Power Query (M)

DAX is easy, CALCULATE makes DAX hard...

Hi @Greg_Deckler,

 

Thank you for your reply, the formula you shared returns the format I was looking for, but when I try to calculate the difference between two dates (date1=(2020;5;1) date2=(2020;5;2)) where the the difference is only 1 day the returned result is totally different  -1 year, 11 months and 1 days.

 

Thank you in advance.

@DataVitalizer - Yeah, I figured that would be the case. It's going to take some tweaking. I'll take a look when I have some time. It's an interesting problem.

 


@ me in replies or I'll lose your thread!!!
Instead of a Kudo, please vote for this idea
Become an expert!: Enterprise DNA
External Tools: MSHGQM
YouTube Channel!: Microsoft Hates Greg
Latest book!:
The Definitive Guide to Power Query (M)

DAX is easy, CALCULATE makes DAX hard...

I made some researches in the meanwhile but still can't find the right formula.

Hoping you can help me community 🙂

 

@DataVitalizer A little tweaking to the @Greg_Deckler formula will work for you...

 

Please try below..

 

DateDiff = 
VAR __daysinMonth = DAY(EOMONTH([Date1],0))
VAR __years = DATEDIFF([Date1],[Date2],YEAR) -1 
VAR __months = IF(MONTH([Date1])<=MONTH([Date2]),MONTH([Date2])-MONTH([Date1]),12-MONTH([Date1])+MONTH([Date2])-1)
VAR __days = IF(DAY([Date1])<DAY([Date2]),DAY([Date2])-DAY([Date1]),DAY([Date2])+(__daysinMonth-DAY([Date1])))
VAR __Final = SWITCH(TRUE(),
                    __years>0,__years & " year(s), " & __months & " month(s) and " & __days & " day(s)",
                    __months>0,__months & " month(s) and " & __days & " day(s)",
                    __days & " day(s)")
RETURN __Final

image.png





Did I answer your question? Mark my post as a solution!

Proud to be a PBI Community Champion




@PattemManohar Thank you for your reply.

 

I am facing a new issue when using the updated fomula, when the exact difference between both dates is one (1) Year the formula returns 30days

new_tab.png

 

Thank you in advance

@DataVitalizer Please try this... Hopefully this should handle all cases...

 

DateDiff = 
VAR __daysinMonth = DAY(EOMONTH([Date1],0))
VAR __years = DATEDIFF([Date1],[Date2],YEAR)
VAR __months = IF(MONTH([Date1])<=MONTH([Date2]),MONTH([Date2])-MONTH([Date1]),12-MONTH([Date1])+MONTH([Date2])-1)
VAR __days = IF(DAY([Date1])<DAY([Date2]),DAY([Date2])-DAY([Date1]),DAY([Date2])+(__daysinMonth-DAY([Date1])))
VAR __Final = SWITCH(TRUE(),
__years>0 && __months = 0,__years & " year(s)",
DAY(Test68DateDiffInWords[Date1])=DAY(Test68DateDiffInWords[Date2]),__months & " month(s)",
__years>0 && __months>0 && __days>0,__years & " year(s), " & __months & " month(s) and " & __days & " day(s)",
__months>0,__months & " month(s) and " & __days & " day(s)",
__days & " day(s)"
)
RETURN __Final

image.png





Did I answer your question? Mark my post as a solution!

Proud to be a PBI Community Champion




Hi @PattemManohar

I had a limited internet acces recently.

I used the updated fomula you have suggested, but still getting wrong results 

 

2018-11-12_130105.png

1/ 12 Nov 2018 - 11 Dec 2018 => 29 days

2/ 12 Nov 2018 - 01 Dec 2018 => 19 days

3/ 12 Nov 2018 - 01 Nov 2019 => 354 days which is even less than 1 year

 

 

@DataVitalizer Hmm Smiley Sad 

Please try this and let me know how it goes with your testing...

  

DateDiff = 
VAR _Years = FLOOR(YEARFRAC([Date1],[Date2],4),1)
VAR _Months = FLOOR(MOD(YEARFRAC([Date1],[Date2],4),1) * 12.0,1)
VAR _daysinMonth = DAY(EOMONTH([Date1],0))
VAR _days = IF(DAY([Date1])<DAY([Date2]),DAY([Date2])-DAY([Date1]),DAY([Date2])+(_daysinMonth-DAY([Date1])))
VAR _daysFinal =  SWITCH(TRUE(),DAY(EOMONTH([Date1],0)) = _days || DAY(EOMONTH([Date2],0)) = _days,0,_days)

RETURN SWITCH(TRUE(),
             _Years>0 && _Months = 0 && _daysFinal = 0,_Years & " year(s)",
             _Years>0 && _Months >0 && _daysFinal >0,_Years & " year(s), " & _Months & " month(s) " & _daysFinal & " day(s)",
             _Months>0 && _daysFinal = 0, _Months & " month(s) ",
             _Months>0 && _daysFinal >0, _Months & " month(s) " & _daysFinal & " day(s)",
             _daysFinal & " day(s)"
             )

 

image.png





Did I answer your question? Mark my post as a solution!

Proud to be a PBI Community Champion




Here are the results

2018-11-13_155145.png

FYI: The date format used in these examples is dd/mm/yyyy

@DataVitalizer Oh !! Ok, please try this (Just added two more conditions in the SWITCH statement)

 

Hopefully, this should fix all your test cases 🙂 Fingers Crossed !!

 

Final = 
VAR _Years = FLOOR(YEARFRAC([Date1],[Date2],4),1)
VAR _Months = FLOOR(MOD(YEARFRAC([Date1],[Date2],4),1) * 12.0,1)
VAR _daysinMonth = DAY(EOMONTH([Date1],0))
VAR _days = IF(DAY([Date1])<DAY([Date2]),DAY([Date2])-DAY([Date1]),DAY([Date2])+(_daysinMonth-DAY([Date1])))
VAR _daysFinal =  SWITCH(TRUE(),DAY(EOMONTH([Date1],0)) = _days || DAY(EOMONTH([Date2],0)) = _days,0,_days)

RETURN SWITCH(TRUE(),
             _Years>0 && _Months = 0 && _daysFinal = 0,_Years & " year(s)",
             _Years>0 && _Months>0 && _daysFinal = 0, _Years & " year(s), " & _Months & " month(s) ",
             _Years>0 && _Months >0 && _daysFinal >0, _Years & " year(s), " & _Months & " month(s) " & _daysFinal & " day(s)",
             _Years>0 && _Months = 0 && _daysFinal >0, _Years & " year(s), " & _daysFinal & " day(s)",
             _Months>0 && _daysFinal = 0, _Months & " month(s) ",
             _Months>0 && _daysFinal >0, _Months & " month(s) " & _daysFinal & " day(s)",
             _daysFinal & " day(s)"
             )

image.png





Did I answer your question? Mark my post as a solution!

Proud to be a PBI Community Champion




Same problem here, same user case. Thanks @PattemManohar and @Greg_Deckler for the help, still working for me and you save me a couple of hours!!

 

Kind regards 

 

ICR

Hi, Will this work if Date2= Table[ColumnDate]. I am trying this but no luck 😞

I just tried the formula the suggested formula using other dates and they are all fixed.

I can say that this formula finally meets what I have been looking for.

 

Thank you @PattemManohar @Greg_Deckler 

@DataVitalizer Smiley Very Happy Finally !!





Did I answer your question? Mark my post as a solution!

Proud to be a PBI Community Champion




Hey, Are Date1, Date2, and Date Diff measures or calculated columns? The images above show like its a calculated column. Please confirm, need this solution to solve another problem. Thanks

Helpful resources

Announcements
Microsoft Fabric Learn Together

Microsoft Fabric Learn Together

Covering the world! 9:00-10:30 AM Sydney, 4:00-5:30 PM CET (Paris/Berlin), 7:00-8:30 PM Mexico City

PBI_APRIL_CAROUSEL1

Power BI Monthly Update - April 2024

Check out the April 2024 Power BI update to learn about new features.

April Fabric Community Update

Fabric Community Update - April 2024

Find out what's new and trending in the Fabric Community.