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

Earn the coveted Fabric Analytics Engineer certification. 100% off your exam for a limited time only!

Reply
elads
Helper III
Helper III

datediff in HH:MM format

Hi,

 

I have two columns:
1. Start time
2. End time.

I want to know the duration of time between the two columns in hour and minute format (HH:MM) 

Then I want to display their summary on the "CARD" in the same format.

Attached is a sample example.

Capture.PNG

Thank you so much for helping.

 

BR,

Alon

 

1 ACCEPTED SOLUTION
Anonymous
Not applicable

Create a calculated column that for each row will store the number of seconds between the two dates. Then take the measure I've shown you and operate on the SUM of the column. So, you should create a measure like [Total Seconds] = SUM ( T[Seconds] ) and then use its value in my measure replacing the part which is responsible for calculating the seconds...

Best
Darek

View solution in original post

14 REPLIES 14
Anonymous
Not applicable

Duration HH:MM:SS = 
// We start with a duration in number of seconds
VAR Duration = DATEDIFF( 'Table'[StartDate], 'Table'[EndDate], SECOND )
// There are 3,600 seconds in an hour
VAR Hours =
    INT ( Duration / 3600)
// There are 60 seconds in a minute
VAR Minutes =
    INT ( MOD( Duration - ( Hours * 3600 ),3600 ) / 60)
// Remaining seconds are the remainder of the seconds divided by 60 after subtracting out the hours 
VAR Seconds =
    ROUNDUP(MOD ( MOD( Duration - ( Hours * 3600 ),3600 ), 60 ),0) // We round up here to get a whole number
// These intermediate variables ensure that we have leading zero's concatenated onto single digits
// Hours with leading zeros
VAR H =
    IF ( LEN ( Hours ) = 1, 
        CONCATENATE ( "0", Hours ),
        CONCATENATE ( "", Hours )
      )
// Minutes with leading zeros
VAR M =
    IF (
        LEN ( Minutes ) = 1,
        CONCATENATE ( "0", Minutes ),
        CONCATENATE ( "", Minutes )
    )
// Seconds with leading zeros
VAR S =
    IF (
        LEN ( Seconds ) = 1,
        CONCATENATE ( "0", Seconds ),
        CONCATENATE ( "", Seconds )
    )
// Now return hours, minutes and seconds with leading zeros in the proper format "hh:mm:ss"
RETURN
    CONCATENATE (
        H,
        CONCATENATE ( ":", CONCATENATE ( M, CONCATENATE ( ":", S ) ) )
    )

This is code from:

 

https://community.powerbi.com/t5/Community-Blog/Aggregating-Duration-Time/ba-p/22486

 

Best

Darek

This was a great solution. Worked like a charm!

Hi,

 

Thank you for your answer,

The result is good, but I have to summarize the hours and minutes.
I don't seem to be able to do that because this field is text.

BR,

Alon

Anonymous
Not applicable

Mate, a little bit of thinking goes a long way... If you have to summarize, then the measure should first add up all the seconds and then apply the above formula to this sum. Is this not obvious?

Best
Darek

Hi @Anonymous,

 

Do you have an example of such a calculation ..? 

Anonymous
Not applicable

Create a calculated column that for each row will store the number of seconds between the two dates. Then take the measure I've shown you and operate on the SUM of the column. So, you should create a measure like [Total Seconds] = SUM ( T[Seconds] ) and then use its value in my measure replacing the part which is responsible for calculating the seconds...

Best
Darek

Hi,

 

I created a calculated column that sums up the seconds between the two columns

sum_Diff_In_Second = sum(Table_Name[Diff_In_second])

Which part of your code should I replace not so clear ..?

Anonymous
Not applicable

"So, you should create a measure like [Total Seconds] = SUM ( T[Seconds] ) and then use its value in my measure replacing the part which is responsible for calculating the seconds..."

 

Use Its value in my measure replacing the part which calculates the seconds...

 

I think this is as clear as the sun. Your "effort" is to find the part that calculates the seconds and substitute the value of the measure for the number of seconds. Can't be any simpler than that.

 

Best

Darek

Mariusz
Community Champion
Community Champion

HI @elads 

Sorry, but who are you replying too?

 

 

Best Regards,
Mariusz

Please feel free to connect with me.
Mariusz Repczynski

 

Hi,

 

Sorry, I answered you @Mariusz 

Mariusz
Community Champion
Community Champion

Hi @elads 

The below Measure does the sum ( SUMX part ), the rest is just formatting it to DD - HH:MM:SS, technically you can use SUMX( 'Table', 'Table'[End] - 'Table'[Start] ) * 1 part on its own, however this would give you only decimal value.

Measure = 
VAR _all = SUMX( 'Table', 'Table'[End] - 'Table'[Start] ) * 1
VAR _days  = INT( _all ) 
VAR _time = _all - _days 
RETURN  FORMAT( _days, "#0D-" ) & FORMAT( _time, "hh:mm:ss")

 

Best Regards,
Mariusz

If this post helps, then please consider Accepting it as the solution.

Please feel free to connect with me.
Mariusz Repczynski

 

Hi,

 

Sorry, I answered you..

Mariusz
Community Champion
Community Champion

Hi @elads 

You can do something like below, you can adjust the code to show only hh:mm if you wish, but the below will address the issue of days when the sum goes over 24.

 

Measure = 
VAR _all = SUMX( 'Table', 'Table'[End] - 'Table'[Start] ) * 1
VAR _days  = INT( _all ) 
VAR _time = _all - _days 
RETURN  FORMAT( _days, "#0D-" ) & FORMAT( _time, "hh:mm:ss")

 

Best Regards,
Mariusz

If this post helps, then please consider Accepting it as the solution.

Please feel free to connect with me.
Mariusz Repczynski

 

Thnaks for information

 

Helpful resources

Announcements
April AMA free

Microsoft Fabric AMA Livestream

Join us Tuesday, April 09, 9:00 – 10:00 AM PST for a live, expert-led Q&A session on all things Microsoft Fabric!

March Fabric Community Update

Fabric Community Update - March 2024

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

Top Solution Authors