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

Find everything you need to get certified on Fabric—skills challenges, live sessions, exam prep, role guidance, and more. Get started

Reply
sonisick
Resolver I
Resolver I

What's the difference between two dax calculations for Date Difference?

What's the difference between two dax calculations for Date Difference?

Duration = Format(LASTDATE(FactInternetSales[DueDate])- FIRSTDATE(FactInternetSales[DueDate]),"0") +1
Difference Last Minus First = ABS(DATEDIFF(LASTDATE(FactInternetSales[DueDate]), FIRSTDATE(FactInternetSales[DueDate]), day))+1
 
If I use the first one on a Matrix display, I can't descend the Hierarchy. I get an error:
Couldn't load the data for this visual: MdxScript(Model) (11,38) Calculation error in measure 'FactInternetSales[Duration]: Cannot convert value '' of type Text to Number.
 
The Second works fine.
 
 

 

1 ACCEPTED SOLUTION
Daryl-Lynch-Bzy
Resident Rockstar
Resident Rockstar

Hi @sonisick - this is make sense because FIRSTDATE - DAX Guide and LASTDATE - DAX Guide are table functions.  This means the function produce results in a Table.  So you are effectively asking for Table A - Table B.  I guess the FORMAT allows the results to be converted to Text String that looks like a number.  When using the DATEDIFF - DAX Guide function instead of minus, the result is a Scalar value.  This mean the function produces a single integer value.

 

Try the following instead as MAX and MIN are scalar functions.

Duration Max/Min = MAX(FactInternetSales[DueDate])- MIN(FactInternetSales[DueDate]) + 1

 

View solution in original post

5 REPLIES 5
Daryl-Lynch-Bzy
Resident Rockstar
Resident Rockstar

Hi @sonisick - this is make sense because FIRSTDATE - DAX Guide and LASTDATE - DAX Guide are table functions.  This means the function produce results in a Table.  So you are effectively asking for Table A - Table B.  I guess the FORMAT allows the results to be converted to Text String that looks like a number.  When using the DATEDIFF - DAX Guide function instead of minus, the result is a Scalar value.  This mean the function produces a single integer value.

 

Try the following instead as MAX and MIN are scalar functions.

Duration Max/Min = MAX(FactInternetSales[DueDate])- MIN(FactInternetSales[DueDate]) + 1

 

Seanan
Solution Supplier
Solution Supplier

Hi @sonisick 


At first glance it is because in your first expression you have 0 wrapped in quotations. By doing this Power BI will then format the expression as text. Could you try removing the quotations to see if this changes anything.

 

Super User Signature.PNG

Thanks for your answer, but unquoting doesn't help the problem.

Daryl-Lynch-Bzy
Resident Rockstar
Resident Rockstar

Hi @sonisick - The FORMAT – DAX Guide function will convert the Number result to Text string.   The ABS value will retain the number value.  This is why the visual is becoming confused when you try sorting the heirarchy.

This is the expression the instructor started from

DurationWOFormat = LASTDATE(FactInternetSales[DueDate])- FIRSTDATE(FactInternetSales[DueDate])
Which gives something totally incomprehensible to me.
Year,Quarter,Month,Day,Earliest DueDate,Latest DueDate,YearStart,DurationWOFormat
2011,Qtr 1,January,10,2011-01-10 00:00:00,2011-01-10 00:00:00,2011-01-10 00:00:00,1899-12-30 00:00:00
2011,Qtr 1,January,11,2011-01-11 00:00:00,2011-01-11 00:00:00,2011-01-10 00:00:00,1899-12-30 00:00:00
2011,Qtr 1,January,12,2011-01-12 00:00:00,2011-01-12 00:00:00,2011-01-10 00:00:00,1899-12-30 00:00:00
2011,Qtr 1,January,13,2011-01-13 00:00:00,2011-01-13 00:00:00,2011-01-10 00:00:00,1899-12-30 00:00:00

Helpful resources

Announcements
Europe Fabric Conference

Europe’s largest Microsoft Fabric Community Conference

Join the community in Stockholm for expert Microsoft Fabric learning including a very exciting keynote from Arun Ulag, Corporate Vice President, Azure Data.

Power BI Carousel June 2024

Power BI Monthly Update - June 2024

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

PBI_Carousel_NL_June

Fabric Community Update - June 2024

Get the latest Fabric updates from Build 2024, key Skills Challenge voucher deadlines, top blogs, forum posts, and product ideas.

Top Solution Authors