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
Anonymous
Not applicable

Addition of time value.

Hi,

I have a column that has data stored in HH:MM: SS format.

I just need the cumulative / sum value of that column in Days:HH:MM: SS.

 

i tried dax function: 

Total Working Time = FORMAT(Sum('report'[column name]), "HH:MM:SS")
that doesnt seem to work as it resets every 24 hours.
 
is there an alternative?
 

image.png

1 ACCEPTED SOLUTION
Icey
Community Support
Community Support

Hi @Anonymous ,

 

Please check if this is what you want:

 

Case 1: Your time column is <24 hours and stored in "Time" type and "HH:MM:SS" format.

24_.jpg

Create a measure like so:

Sum Measure <24 hours = 
VAR Seconds1 =
    SUMX ( 'Table', SECOND ( 'Table'[<24hours] ) )
VAR Minutes1 =
    SUMX ( 'Table', MINUTE ( 'Table'[<24hours] ) )
VAR Hours1 =
    SUMX ( 'Table', HOUR ( 'Table'[<24hours] ) )
VAR Seconds2 =
    MOD ( Seconds1, 60 )
VAR Minutes2 =
    MOD ( TRUNC ( Seconds1 / 60 ) + Minutes1, 60 )
VAR Hours2 =
    MOD ( Hours1 + TRUNC ( ( TRUNC ( Seconds1 / 60 ) + Minutes1 ) / 60 ), 24 )
VAR Days =
    TRUNC (
        (
            Hours1
                + TRUNC ( ( TRUNC ( Seconds1 / 60 ) + Minutes1 ) / 60 )
        ) / 24
    )
RETURN
    FORMAT ( Days, "00" ) & ":"
        & FORMAT ( Hours2, "00" ) & ":"
        & FORMAT ( Minutes2, "00" ) & ":"
        & FORMAT ( Seconds2, "00" )

 

Case 2: Your time column is >24 hours and stored in "Text" type and "Text" format.

24__.PNG

Create a measure like so:

Sum Measure >24 hours = 
VAR Seconds1 =
    SUMX ( 'Table', CALCULATE ( VALUE ( RIGHT ( MAX ( 'Table'[>24hours] ), 2 ) ) ) )
VAR Minutes1 =
    SUMX (
        'Table',
        CALCULATE ( VALUE ( LEFT ( RIGHT ( MAX ( 'Table'[>24hours] ), 5 ), 2 ) ) )
    )
VAR Hours1 =
    SUMX ( 'Table', CALCULATE ( VALUE ( LEFT ( MAX ( 'Table'[>24hours] ), 2 ) ) ) )
VAR Seconds2 =
    MOD ( Seconds1, 60 )
VAR Minutes2 =
    MOD ( TRUNC ( Seconds1 / 60 ) + Minutes1, 60 )
VAR Hours2 =
    MOD ( Hours1 + TRUNC ( ( TRUNC ( Seconds1 / 60 ) + Minutes1 ) / 60 ), 24 )
VAR Days =
    TRUNC (
        (
            Hours1
                + TRUNC ( ( TRUNC ( Seconds1 / 60 ) + Minutes1 ) / 60 )
        ) / 24
    )
RETURN
    FORMAT ( Days, "00" ) & ":"
        & FORMAT ( Hours2, "00" ) & ":"
        & FORMAT ( Minutes2, "00" ) & ":"
        & FORMAT ( Seconds2, "00" )

 

The results:

24.PNG

For more details, please check the attached PBIX file.

 

 

Best Regards,

Icey

 

If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

View solution in original post

3 REPLIES 3
Icey
Community Support
Community Support

Hi @Anonymous ,

 

Please check if this is what you want:

 

Case 1: Your time column is <24 hours and stored in "Time" type and "HH:MM:SS" format.

24_.jpg

Create a measure like so:

Sum Measure <24 hours = 
VAR Seconds1 =
    SUMX ( 'Table', SECOND ( 'Table'[<24hours] ) )
VAR Minutes1 =
    SUMX ( 'Table', MINUTE ( 'Table'[<24hours] ) )
VAR Hours1 =
    SUMX ( 'Table', HOUR ( 'Table'[<24hours] ) )
VAR Seconds2 =
    MOD ( Seconds1, 60 )
VAR Minutes2 =
    MOD ( TRUNC ( Seconds1 / 60 ) + Minutes1, 60 )
VAR Hours2 =
    MOD ( Hours1 + TRUNC ( ( TRUNC ( Seconds1 / 60 ) + Minutes1 ) / 60 ), 24 )
VAR Days =
    TRUNC (
        (
            Hours1
                + TRUNC ( ( TRUNC ( Seconds1 / 60 ) + Minutes1 ) / 60 )
        ) / 24
    )
RETURN
    FORMAT ( Days, "00" ) & ":"
        & FORMAT ( Hours2, "00" ) & ":"
        & FORMAT ( Minutes2, "00" ) & ":"
        & FORMAT ( Seconds2, "00" )

 

Case 2: Your time column is >24 hours and stored in "Text" type and "Text" format.

24__.PNG

Create a measure like so:

Sum Measure >24 hours = 
VAR Seconds1 =
    SUMX ( 'Table', CALCULATE ( VALUE ( RIGHT ( MAX ( 'Table'[>24hours] ), 2 ) ) ) )
VAR Minutes1 =
    SUMX (
        'Table',
        CALCULATE ( VALUE ( LEFT ( RIGHT ( MAX ( 'Table'[>24hours] ), 5 ), 2 ) ) )
    )
VAR Hours1 =
    SUMX ( 'Table', CALCULATE ( VALUE ( LEFT ( MAX ( 'Table'[>24hours] ), 2 ) ) ) )
VAR Seconds2 =
    MOD ( Seconds1, 60 )
VAR Minutes2 =
    MOD ( TRUNC ( Seconds1 / 60 ) + Minutes1, 60 )
VAR Hours2 =
    MOD ( Hours1 + TRUNC ( ( TRUNC ( Seconds1 / 60 ) + Minutes1 ) / 60 ), 24 )
VAR Days =
    TRUNC (
        (
            Hours1
                + TRUNC ( ( TRUNC ( Seconds1 / 60 ) + Minutes1 ) / 60 )
        ) / 24
    )
RETURN
    FORMAT ( Days, "00" ) & ":"
        & FORMAT ( Hours2, "00" ) & ":"
        & FORMAT ( Minutes2, "00" ) & ":"
        & FORMAT ( Seconds2, "00" )

 

The results:

24.PNG

For more details, please check the attached PBIX file.

 

 

Best Regards,

Icey

 

If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

Anonymous
Not applicable

Hi @amitchandak
I went through the links but still have doubts and confusions since I'm new to power bi.
Can you please help me by sending the Dax code for the same. It would be a huge help. Thanks

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.