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.

Greg_Deckler

Aggregating Duration/Time

This is a collaborative blog post by @konstantinos and @Greg_Deckler resulting from the forum discussion topic “Aggregating Duration/Time”. http://community.powerbi.com/t5/Desktop/Aggregating-Duration-Time/m-p/13350/highlight/true#M3358

 

Introduction

Both Excel and DAX lack support for a true time duration data type making the display of duration in a format such as “HH:MM:SS” problematic. However, with some creative formulas, this problem can be solved.

 

Scenario

Consider a scenario where you have a number of seconds worked on a help desk ticket or the duration of a phone call in number of seconds. You desire to put this into a more standardized time duration format such as “HH:MM:SS”.

Here is a small sample of data to work with:

 

Item,Duration in Seconds

Phone Call 1, 45

Phone Call 2, 2875

Phone Call 3, 8944

 

Excel

In Excel, we would have the Item descriptions in column 1, A and Duration in Seconds in column 2, B. We could create the following additional columns to solve the problem:

  • Hours (C column): = INT(B2/3600)
  • Minutes (D column): = INT(MOD(B2,3600)/60)
  • Seconds (E column): = MOD(MOD(B2,3600)/60)

 

However, these calculations do not account for leading zeros and we might end up with a duration of “4:2:8” for four hours, two minutes and eight seconds. Not exactly what we want. So, we have to add more columns:

  • H (F column): =IF(LEN(C2)=1,CONCATENATE("0",C2),CONCATENATE("",C2))
  • M (G column): =IF(LEN(D2)=1,CONCATENATE("0",D2),CONCATENATE("",D2))
  • S (H column): =IF(LEN(E2)=1,CONCATENATE("0",E2),CONCATENATE("",E2))

 

For Duration, we cannot use the TIME function of Excel as this would return a point in time, such as 12:47 AM. Therefore, we must use CONCATENATE:

  • Duration (I column): =CONCATENATE(F2,":",G2,":",H2)

 

Now we have the Duration in the desired format. Unfortunately, we also have six extra columns cluttering things up. We could hide those columns in the Excel interface or we might even combine everything into a single formula:

  • Duration: =CONCATENATE(IF(LEN(INT(B2/3600))=1,CONCATENATE("0",INT(B2/3600)),CONCATENATE("",INT(B2/3600))),":",IF(LEN(INT(MOD(B2,3600)/60))=1,CONCATENATE("0",INT(MOD(B2,3600)/60)),CONCATENATE("",INT(MOD(B2,3600)/60))),":",IF(LEN(MOD(MOD(B2,3600),60))=1,CONCATENATE("0",MOD(MOD(B2,3600),60)),CONCATENATE("",MOD(MOD(B2,3600),60))))

 

If you are a fan of this second option, you have likely spent far too much time writing Perl code and need to seek professional counseling.

 

The problem is that both of these options are sub-optimal. When someone else looks at what has been done, or even if you were to look at this 6 months from now, you would essentially have to reverse engineer what has been done, which could take a significant amount of time and troubleshooting. For example, what if one of the “3600” had been mistakenly entered as “360” and was causing a problem? Tracking that down could take some time.

 

DAX

There are so many similarities between DAX and Excel that our functions are nearly identical. Given the same data and the columns [Item] and [Duration in Seconds], our initial formulas are identical other than the naming convention for the cell/column:

  • Hours = INT([Duration in Seconds]/3600)
  • Minutes = INT(MOD([Duration in Seconds],3600)/60)
  • Seconds = MOD(MOD([Duration in Seconds],3600),60)
  • H = IF(LEN([Hours])=1,CONCATENATE("0",[Hours]),CONCATENATE("",[Hours]))
  • M = IF(LEN([Minutes])=1,CONCATENATE("0",[Minutes]),CONCATENATE("",[Minutes]))
  • S = IF(LEN([Seconds])=1,CONCATENATE("0",[Seconds]),CONCATENATE("",[Seconds]))

 

One difference between DAX and Excel however is that DAX’s CONCATENATE function only accepts two arguments, so the final Duration column formula becomes:

  • Duration = CONCATENATE([H],CONCATENATE(":",CONCATENATE([M],CONCATENATE(":",[S]))))

 

Just like Excel, we could combine all of those formulas into a single massive formula, but we have no desire to make your eyes bleed. Thus, we are left in the same predicament as Excel when it comes to maintainability, supportability and overall readability of the solution. Or are we?

 

A Better Solution in DAX

Luckily, the powerful language-like features of DAX, comments and variables, help us improve our solution dramatically.

Consider the following DAX “formula”:

 

Duration = 
// Duration formatting 
// * @konstatinos 1/25/2016
// * Given a number of seconds, returns a format of "hh:mm:ss"
//
// We start with a duration in number of seconds
VAR Duration = [Duration in Seconds]
// 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 ) ) )
    )

 

Conclusion

The techniques shown here allow us to solve the problem of the lack of a true time duration data type in both Excel and DAX. Ultimately, DAX allows us to create a superior solution due to its support for powerful programming-language-like features such as comments and variables without resorting to a completely different programming language such as VBScript.

Comments

@ankush9646 Maybe for the RETURN statement maybe:

RETURN

IF( [AvgHoldTime] = BLANK(), BLANK(),

CONCATENATE (
H,
CONCATENATE ( ":", CONCATENATE ( M, CONCATENATE ( ":", S ) ) )
)

)

 

thank you @Greg_Deckler  for the quick reply. 
I tried this logic and it worked for me.
H & IF(M<>"",":" &M) & IF(S<>"",":" &S). Also tried logic provided by you it also worked.

RETURN

IF( [AvgHoldTime] = BLANK(), BLANK(),

CONCATENATE (
H,
CONCATENATE ( ":", CONCATENATE ( M, CONCATENATE ( ":", S ) ) )
)

)
I am trying to use this logic before declaring the variables but getting error. Can we put this return logic before the variables declared so that it should filter out the values based on average hold time before executing it.

AvgHold =
// Duration formatting
// * @konstatinos 1/25/2016
// * Given a number of seconds, returns a format of "hh:mm:ss"
//
// We start with a duration in number of seconds

VAR Duration = [AvgHoldTime]
// There are 3,600 seconds in an hour

RETURN

     IF( [AvgHoldTime] = BLANK(), BLANK(),

     CONCATENATE (
     H,
     CONCATENATE ( ":", CONCATENATE ( M, CONCATENATE ( ":", S ) ) )
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 )
    )
RETURN

     IF( [AvgHoldTime] = BLANK(), BLANK(),

     CONCATENATE (
     H,
     CONCATENATE ( ":", CONCATENATE ( M, CONCATENATE ( ":", S ) ) )
)

)
   



Here follows some tweaks I've made in order to be able to order by time from the smallest to the largest or the other way around. The formula provided by @Greg_Deckler is great, but one wont be able to do what I've said previously, so here follows some tweaks on the formula as well as in the Measure tools format:

 

VAR Duration = [measure] * 24 * 60 * 60 -- tweak in order to get the number in seconds
VAR Hours =
    INT ( Duration / 3600)
VAR Minutes =
    INT ( MOD( Duration - ( Hours * 3600 ),3600 ) / 60)
VAR Seconds =
    ROUNDUP(MOD ( MOD( Duration - ( Hours * 3600 ),3600 ), 60 ),0)
VAR H =
    IF ( LEN ( Hours ) = 1, 
        CONCATENATE ( "0", Hours ),
        CONCATENATE ( BLANK(), Hours )
      )
VAR M =
    IF (
        LEN ( Minutes ) = 1,
        CONCATENATE ( "0", Minutes ),
        CONCATENATE ( BLANK(), Minutes )
    )
VAR S =
    IF (
        LEN ( Seconds ) = 1,
        CONCATENATE ( "0", Seconds ),
        CONCATENATE ( BLANK(), Seconds )
    )
RETURN VALUE(H & M & S)

 

The last adjust is this one Untitled.png

 

Looking at both measures (the one I've previously provided and the original one provided by @Greg_Deckler ) gets two different behaviours when sorting a matrix by the measures, as follows:

 

conv_format.pngDuration.png

But can you display this in report view. I searched for the issue and found out that only columns of text type can be displayed.

Unless your duration in seconds doesn't exceed 32750 (arround 9 hours), you can simply use the following:

Measure = TIME(0,0,[duration in seconds])


"DAX’s CONCATENATE function only accepts two arguments" - how f^cking ridiculous.

 

Why is EVERYTHING in DAX so lame? 20 year-old Excel seems more thought out. PBI seems slapped together with functions from randomly selected suggestions.

Hi all, 

@Greg_Deckler and @konstantinos this really helped but I'm facing an issue. I have a column "TTR SLA Breached" that compares the results in "Final TTR format" with a target "SLA TTR" (formated as text, same as this code) and if the result is greater than the target it should return TRUE, else FALSE. It's working good but for some reason values over 99 do not return TRUE.

MrFox_0-1709814253010.png

I'm pretty new with Power BI and DAX so am I missing something here ? 

 

Thanks in advance

I appeciate the step by step calculation, but the end function is needlessly verbose:

Duration = 
RIGHT("0" & INT([Duration in Seconds] / 3600), 2) & ":" &
RIGHT("0" & INT(MOD([Duration in Seconds], 3600) / 60), 2) & ":" &
RIGHT("0" & INT(MOD([Duration in Seconds], 60)), 2)