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

Enhance your career with this limited time 50% discount on Fabric and Power BI exams. Ends August 31st. Request your voucher.

Reply
EBI621
New Member

Converting seconds into aggregated HH:MM:SS in a Matrix

I have a data set with the case number processed by each associate and the time spent in sec. The report has a date range slicer to control which date ranges we want to look at the efforts on.  

 

Sample dataset:

DateAssociate NameCases DoneEffort (seconds)
1/1/19John Smith2100
1/2/19John Smith2150
1/1/19Jane Doe150
1/3/19John Smith4200

 

The Matrix I need to build will summarize the average effort each associate spends on a case per day and converted to HH:MM:SS format. The Associate Name field is being used under columns for the Matrix

 

Matrix:

DateJohn SmithJane DoeTotal
1/1/190:00:500:00:500:01:40
1/2/190:01:1500:01:15
1/3/190:00:5000:00:50

 

I've tried some of the solutions posted in other threads to format the time in HH:MM:SS but those end up displaying all the rows in the Matrix rather than the dates selected in the slicer so I believe those work if the values are displayed as a column rather than aggregated. Is it possible to create a measure that can retain the calculations but simply display the values in a duration format?

 

 

 

 

1 ACCEPTED SOLUTION
MFelix
Super User
Super User

Hi @EBI621 ,

 

Create the following two measures:

 

Time Value = 
IF (
    HASONEVALUE ( 'Table'[Associate Name] );
    SUM ( 'Table'[Effort (seconds)] ) / SUM ( 'Table'[Cases Done] );
    SUMX (
        VALUES ( 'Table'[Associate Name] );
        SUM ( 'Table'[Effort (seconds)] ) / SUM ( 'Table'[Cases Done] )
    )
)


Duration Selected Period = 
// 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 = [Time Value] * 60
// 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 ( ""; 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();BLANK();

    CONCATENATE (
        H;
        //CONCATENATE ( ":", CONCATENATE ( M, CONCATENATE ( ":", S ) ) )        
        CONCATENATE ( "h"; CONCATENATE(M;"m" ) )
    ))

 

 

Result below and in attach file.

MFelix_0-1605888827965.png

 


Regards

Miguel Félix


Did I answer your question? Mark my post as a solution!

Proud to be a Super User!

Check out my blog: Power BI em Português



View solution in original post

2 REPLIES 2
Anonymous
Not applicable

Hi @EBI621 ,

 

Check this vedio.

https://www.youtube.com/watch?v=V6GW6Z0-pFo 

 

Best Regards,

Jay

MFelix
Super User
Super User

Hi @EBI621 ,

 

Create the following two measures:

 

Time Value = 
IF (
    HASONEVALUE ( 'Table'[Associate Name] );
    SUM ( 'Table'[Effort (seconds)] ) / SUM ( 'Table'[Cases Done] );
    SUMX (
        VALUES ( 'Table'[Associate Name] );
        SUM ( 'Table'[Effort (seconds)] ) / SUM ( 'Table'[Cases Done] )
    )
)


Duration Selected Period = 
// 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 = [Time Value] * 60
// 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 ( ""; 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();BLANK();

    CONCATENATE (
        H;
        //CONCATENATE ( ":", CONCATENATE ( M, CONCATENATE ( ":", S ) ) )        
        CONCATENATE ( "h"; CONCATENATE(M;"m" ) )
    ))

 

 

Result below and in attach file.

MFelix_0-1605888827965.png

 


Regards

Miguel Félix


Did I answer your question? Mark my post as a solution!

Proud to be a Super User!

Check out my blog: Power BI em Português



Helpful resources

Announcements
August Power BI Update Carousel

Power BI Monthly Update - August 2025

Check out the August 2025 Power BI update to learn about new features.

August 2025 community update carousel

Fabric Community Update - August 2025

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

Top Solution Authors