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!

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

Thanks for the ideas! As you mentioned, because this is a text string, unfortunately I cannot get it to work with a bar chart. One suggestion, a person can work around the nested CONCATENATE function at the end to avoid the two string limit by doing this instead:

RETURN
  H & ":" & M & ":" & S.

Alopez, I'd calculate the average time in a seperate measure first then convert the measure such as:

AvgTotDurTime = 
VAR Duration = [AvgTotalDurSecs]
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 ( "", Hours ))
VAR M = IF (LEN ( Minutes ) = 1, CONCATENATE ( "0", Minutes ), CONCATENATE ( "", Minutes ))
VAR S = IF (LEN ( Seconds ) = 1, CONCATENATE ( "0", Seconds ), CONCATENATE ( "", Seconds ))
RETURN
IFERROR( 
IF ([AvgTotalDurSecs]>0, CONCATENATE (H, CONCATENATE ( ":", CONCATENATE ( M, CONCATENATE ( ":", S ) ) )),BLANK())
,BLANK())

The solutions here are okay for a single card value, but as they yield strings they are no good for maths based functionality.

 

It is an astonishing omission from Power BI that there is no Duration type when you create reports.

I agree, what is really needed is a Duration format for numbers.

Hi @Greg_Deckler,

 

What happened to the potential owner of this after the MVP Summit?

 

I had considered using R, but the limitation of needing a Pro license to view an R tile in a report makes it a non-starter.

Anonymous

Unfortunately this options doesn't work for charts like column charts or line charts.

@Anonymous- Agreed, it is a work-a-round. Until they put something like a formatting option for numbers for duration this will continue to be an issue.

This helped loads, thank!

Anonymous

This is taking forever unfortunately 😞

And when you have your column in time format and you want to do the average of this column, but, you're using DirectQuery mode. Time format: HH:mm: ss

Could someone help me?

Thanks, nice article

I believe that all of the functions used are optimized for DirectQuery so you should be able to use them in any DAX formula.

 

https://docs.microsoft.com/en-us/sql/analysis-services/tabular-models/dax-formula-compatibility-in-d...

Yes @Greg_Deckler, you're right!

I said that because of the data modeling, but now I have my answers.
One more thing..

Do you  know how to convert (dd/MM/yyyy HH:mm: ss) into seconds?

Thanks @Greg_Deckler

@ Greg_Deckler...

 

This is amazing.. You have saved me a with this..

 

Dont know why the results of Calculated field in Excel and the results of New Column or measure for Timer function is different on Power Bi,,,

 

But this little tweak...!!! Great.. Thanks a Lot...

Can I get the dax formula to convert   Ex- 2.18 in HH:MM ?

 

NOTE - IF 1 =60 MINS

                

Hi @Greg_Deckler ,

 

I really appreciate your effort. It really helps until we get the duration format.

 

But, I come up with 2 minor issues when I applied this code for my excercise and they are as follows:

  • If the value is blank, it shows "::"

Picture1.png

  • Issue with seconds while rounding up to "60"

Picture2.png

 

And, I think we can improve it with following changes in the code:

  • By adding an if statement to handle the blanks: 
    RETURN
        IF(
            Duration<>BLANK(),
            CONCATENATE (
                H,
                CONCATENATE ( ":", CONCATENATE ( M, CONCATENATE ( ":", S ) ) )
            ),
            BLANK()
        )
  • Instead of rounding up the values, we may round down the values:
    VAR Seconds =
    ROUNDDOWN(MOD ( MOD( Duration - ( Hours * 3600 ),3600 ), 60 ),0)

Complete Code:

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 =
    ROUNDDOWN(MOD ( MOD( Duration - ( Hours * 3600 ),3600 ), 60 ),0) // We round down 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
    IF(
        Duration<>BLANK(),
        CONCATENATE (
            H,
            CONCATENATE ( ":", CONCATENATE ( M, CONCATENATE ( ":", S ) ) )
        ),
        BLANK()
    )