Find everything you need to get certified on Fabric—skills challenges, live sessions, exam prep, role guidance, and more. Get started
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:
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:
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:
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:
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:
One difference between DAX and Excel however is that DAX’s CONCATENATE function only accepts two arguments, so the final Duration column formula becomes:
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.
You must be a registered user to add a comment. If you've already registered, sign in. Otherwise, register and sign in.