Power query - how to support over 24 hours time

mlcalves

New Member
Joined
Mar 10, 2021
Messages
47
Office Version
  1. 2019
  2. 2016
  3. 2013
Platform
  1. Windows
Hi people;

I have a table with hours:

1656695934685.png


When i tried to import this table from powerquery, i get error, even if if change the type to duration:

It puts the date like this:

1656696024694.png


Power Query:
= Table.TransformColumnTypes(#"Promoted Headers",{{"horas gastas", type duration}})

when i click on Error: it says:
DataFormat.Error: We couldn't convert to Duration.
Details:
31/12/1899 20:00:00


Thank you

Regards
 

Excel Facts

Excel motto
Not everything I do at work revolves around Excel. Only the fun parts.
Try converting to date/time, then extracting the time.
hi. thank you. but doesnt work. system converts hours to 01 -24h, when have for example: 40::00:00.

i extrated the time, and nex converted to duration, but doens't work. i think:

1656758753660.png


can anyone help, please?

Thank you
 
Upvote 0
Hi. i discovered this solution:

Power query, in table, add custom column:

Duration in seconds = Duration.TotalSeconds([horas gastas] - #datetime(1899, 12, 31, 0, 0, 0))

Power Query:
 #"Added Custom" = Table.AddColumn(#"Removed Other Columns", "Duration in seconds", each Duration.TotalSeconds([horas gastas] - #datetime(1899, 12, 31, 0, 0, 0)))

Then, close & Apply

then go to report, add measure to convert seconds to time. found this on google.

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 = sum(Sheet1[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 ) ) )
    )
 
Upvote 0

Forum statistics

Threads
1,215,260
Messages
6,123,926
Members
449,135
Latest member
NickWBA

We've detected that you are using an adblocker.

We have a great community of people providing Excel help here, but the hosting costs are enormous. You can help keep this site running by allowing ads on MrExcel.com.
Allow Ads at MrExcel

Which adblocker are you using?

Disable AdBlock

Follow these easy steps to disable AdBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the icon in the browser’s toolbar.
2)Click on the "Pause on this site" option.
Go back

Disable AdBlock Plus

Follow these easy steps to disable AdBlock Plus

1)Click on the icon in the browser’s toolbar.
2)Click on the toggle to disable it for "mrexcel.com".
Go back

Disable uBlock Origin

Follow these easy steps to disable uBlock Origin

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back

Disable uBlock

Follow these easy steps to disable uBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back
Back
Top