Fabric is Generally Available. Browse Fabric Presentations. Work towards your Fabric certification with the Cloud Skills Challenge.
Hi guys, I need help with this:
given the following set of data, calculate time between the 2 dates in different rows. (Please note that I am converting time and date into number format for dates and times, this way it is easier to calculate date with time accurately, however if this is the wrong approach let me know). Thank you!
EVENT | EVENT FROM DATE&TIME | EVENT TO DATE&TIME |
(1) A | 44256.3333333333 | 44265.66768845 |
(2) B | 44267.9546523445 | 44268.000000000 |
(3) C | 44280.6546512324 | 44500.654852256 |
The objective would be to calculate longest time between events, for example:
Event A happened from 44256.3... until 44265.6..., therefore, uneventful time was from 44265.6... until Event B at 44267.9...
Anyone has any ideas on how best to approach this? (first event would theoretically return an error but that's fine).
Solved! Go to Solution.
Hi @pmeyp ,
Create an index column and use the following formula.
Column =
var last_event = CALCULATE(MAX('Table'[EVENT FROM DATE&TIME]),FILTER('Table','Table'[Index]=EARLIER('Table'[Index])-1))
return
IF(ISBLANK(last_event),BLANK(),'Table'[EVENT FROM DATE&TIME]-last_event)
In addition, you could use DATEDIFF() function so that you don't have to convert time value to number value.
https://docs.microsoft.com/en-us/dax/datediff-function-dax
Best Regards,
Jay
Hi @pmeyp ,
Create an index column and use the following formula.
Column =
var last_event = CALCULATE(MAX('Table'[EVENT FROM DATE&TIME]),FILTER('Table','Table'[Index]=EARLIER('Table'[Index])-1))
return
IF(ISBLANK(last_event),BLANK(),'Table'[EVENT FROM DATE&TIME]-last_event)
In addition, you could use DATEDIFF() function so that you don't have to convert time value to number value.
https://docs.microsoft.com/en-us/dax/datediff-function-dax
Best Regards,
Jay
Hello @pmeyp ,
add a new calculated column and calculate the difference:
Difference = myTable[EVENT TO DATE&TIME] - myTable[EVENT FROM DATE&TIME]
Then you can search or filter for the MAX and you should have the row with the longest duration.
If you need any help please let me know.
If I answered your question I would be happy if you could mark my post as a solution ✔️ and give it a thumbs up 👍
Best regards
Denis
Blog: WhatTheFact.bi
Hey @selimovd ,
This is not what I am looking for -- I want to calculate FROM time in Event B minus TO time in Event A (as this calculation yields the time in between events, not duration of event).
Any other ideas? 🤔
Check out the November 2023 Power BI update to learn about new features.
Read the latest Fabric Community announcements, including updates on Power BI, Synapse, Data Factory and Data Activator.