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.

Reply
unnijoy
Post Partisan
Post Partisan

How to get the total time in HH:MM:SS

 

I have the total time people working on a project. But when i put it on table the toal sum is not comming correct.

 

MonthCountryTime#
February-20Brazil7.47.12
February-20Bulgaria5.11.29
February-20Canada20.47.21
February-20China10.06.00
February-20Colombia9.25.59
February-20Costa Rica11.25.57
February-20Dominican Republic18.28.32
Total11.12.30

Here we can see that it is not going beyong 24. How can we get the correct total. As we can see that the total is beyond 11:12:30

1 ACCEPTED SOLUTION
Icey
Community Support
Community Support

Hi @unnijoy ,

 

If the data type of "Time#" column is Text, try this:

 

In Power Query Editor,

1. Relpace value.

replace.PNG

 

2. Change data type.

change data type.jpg

 

In Power BI Desktop,

3. Create a Measure like so:

 

Sum Time Measure =
VAR Seconds1 =
    SUMX ( 'Table', SECOND ( 'Table'[Time#] ) )
VAR Minutes1 =
    SUMX ( 'Table', MINUTE ( 'Table'[Time#] ) )
VAR Hours1 =
    SUMX ( 'Table', HOUR ( 'Table'[Time#] ) )
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 Days1 =
    TRUNC (
        (
            Hours1
                + TRUNC ( ( TRUNC ( Seconds1 / 60 ) + Minutes1 ) / 60 )
        ) / 24
    )
RETURN
    IF (
        Days1 > 0,
        Days1 & ":"
            & FORMAT ( Hours2, "00" ) & ":"
            & FORMAT ( Minutes2, "00" ) & ":"
            & FORMAT ( Seconds2, "00" ),
        Hours2 & ":"
            & FORMAT ( Minutes2, "00" ) & ":"
            & FORMAT ( Seconds2, "00" )
    )

 

Or, 

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

 

sum.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 @unnijoy ,

 

Is this problem solved?

 

 

Best Regards,

Icey

Icey
Community Support
Community Support

Hi @unnijoy ,

 

If the data type of "Time#" column is Text, try this:

 

In Power Query Editor,

1. Relpace value.

replace.PNG

 

2. Change data type.

change data type.jpg

 

In Power BI Desktop,

3. Create a Measure like so:

 

Sum Time Measure =
VAR Seconds1 =
    SUMX ( 'Table', SECOND ( 'Table'[Time#] ) )
VAR Minutes1 =
    SUMX ( 'Table', MINUTE ( 'Table'[Time#] ) )
VAR Hours1 =
    SUMX ( 'Table', HOUR ( 'Table'[Time#] ) )
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 Days1 =
    TRUNC (
        (
            Hours1
                + TRUNC ( ( TRUNC ( Seconds1 / 60 ) + Minutes1 ) / 60 )
        ) / 24
    )
RETURN
    IF (
        Days1 > 0,
        Days1 & ":"
            & FORMAT ( Hours2, "00" ) & ":"
            & FORMAT ( Minutes2, "00" ) & ":"
            & FORMAT ( Seconds2, "00" ),
        Hours2 & ":"
            & FORMAT ( Minutes2, "00" ) & ":"
            & FORMAT ( Seconds2, "00" )
    )

 

Or, 

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

 

sum.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.

az38
Community Champion
Community Champion

@unnijoy 

how do you calculate yout Time# field?

If it is a data source field what Date type it has in Power Query Edtor mode?

You cant try execute replace value in Power query and replace dots "." to ":" then set date type as duration

also check summari type in Column Time# settings in Visualization Pane


do not hesitate to give a kudo to useful posts and mark solutions as solution
LinkedIn

Helpful resources

Announcements
Microsoft Fabric Learn Together

Microsoft Fabric Learn Together

Covering the world! 9:00-10:30 AM Sydney, 4:00-5:30 PM CET (Paris/Berlin), 7:00-8:30 PM Mexico City

PBI_APRIL_CAROUSEL1

Power BI Monthly Update - April 2024

Check out the April 2024 Power BI update to learn about new features.

April Fabric Community Update

Fabric Community Update - April 2024

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