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

Over 24 hour extraction from YYYY-MM-DD HH:MM:SS

Hi everyone. I am quite new to the Power BI and all the DAX things. But here is the problem. I am taking data to Power BI query from an excel file where one collumn is formated in [h]:mm:ss format to get time formation of more than 24 hours as You can see in the example.Excel1.png

But when this data is inserted into Power Query I get these kind of values,
For example 43:00:00 hours are converted into 1900-01-01 19:00:00, same are for the others as well. Example attached.
My question is what is the best way to get the real time, probably in duration format where I can get the needed time in format like 43:00:00 or even in decimal numbers if it is possible. Can I transform the data in Power Query or I need some kind of formula in new calculated column? Big thanks in advance.

2 ACCEPTED SOLUTIONS
Greg_Deckler
Super User
Super User

You can bring it in as text and then I would recommend these two links:

 

https://community.powerbi.com/t5/Community-Blog/Aggregating-Duration-Time/ba-p/22486

https://community.powerbi.com/t5/Quick-Measures-Gallery/Chelsie-Eiden-s-Duration/td-p/793639


@ me in replies or I'll lose your thread!!!
Instead of a Kudo, please vote for this idea
Become an expert!: Enterprise DNA
External Tools: MSHGQM
YouTube Channel!: Microsoft Hates Greg
Latest book!:
The Definitive Guide to Power Query (M)

DAX is easy, CALCULATE makes DAX hard...

View solution in original post

Icey
Community Support
Community Support

Hi @Anonymous ,

 

Power BI doesn't support Duration data type for time over 24 hours.

duration type.PNG

duration type 2.PNG

One workaround, you can transform your time data to 'Second'.

duration type 4.PNG

The complete code is as follows:

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WMjKxMjCwMjBUitUBcoytTC2BSCk2FgA=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type text) meta [Serialized.Text = true]) in type table [Column1 = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Column1", type text}}),
    #"Duplicated Column" = Table.DuplicateColumn(#"Changed Type", "Column1", "Column1 - Copy"),
    #"Split Column by Delimiter" = Table.SplitColumn(#"Duplicated Column", "Column1 - Copy", Splitter.SplitTextByDelimiter(":", QuoteStyle.Csv), {"Column1 - Copy.1", "Column1 - Copy.2", "Column1 - Copy.3"}),
    #"Changed Type1" = Table.TransformColumnTypes(#"Split Column by Delimiter",{{"Column1 - Copy.1", Int64.Type}, {"Column1 - Copy.2", Int64.Type}, {"Column1 - Copy.3", Int64.Type}}),
    #"Added Custom" = Table.AddColumn(#"Changed Type1", "Second", each [#"Column1 - Copy.1"]*3600+[#"Column1 - Copy.2"]*60+[#"Column1 - Copy.3"]),
    #"Removed Columns" = Table.RemoveColumns(#"Added Custom",{"Column1 - Copy.1", "Column1 - Copy.2", "Column1 - Copy.3"})
in
    #"Removed Columns"

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 ,

 

Power BI doesn't support Duration data type for time over 24 hours.

duration type.PNG

duration type 2.PNG

One workaround, you can transform your time data to 'Second'.

duration type 4.PNG

The complete code is as follows:

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WMjKxMjCwMjBUitUBcoytTC2BSCk2FgA=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type text) meta [Serialized.Text = true]) in type table [Column1 = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Column1", type text}}),
    #"Duplicated Column" = Table.DuplicateColumn(#"Changed Type", "Column1", "Column1 - Copy"),
    #"Split Column by Delimiter" = Table.SplitColumn(#"Duplicated Column", "Column1 - Copy", Splitter.SplitTextByDelimiter(":", QuoteStyle.Csv), {"Column1 - Copy.1", "Column1 - Copy.2", "Column1 - Copy.3"}),
    #"Changed Type1" = Table.TransformColumnTypes(#"Split Column by Delimiter",{{"Column1 - Copy.1", Int64.Type}, {"Column1 - Copy.2", Int64.Type}, {"Column1 - Copy.3", Int64.Type}}),
    #"Added Custom" = Table.AddColumn(#"Changed Type1", "Second", each [#"Column1 - Copy.1"]*3600+[#"Column1 - Copy.2"]*60+[#"Column1 - Copy.3"]),
    #"Removed Columns" = Table.RemoveColumns(#"Added Custom",{"Column1 - Copy.1", "Column1 - Copy.2", "Column1 - Copy.3"})
in
    #"Removed Columns"

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

I have also found a solution which works for me as well. I am using a DATEDIFF formula to get decimal numbers. So for example if the column is named "TIME" which I want to convert to decimal number, the formula looks like this:

=datediff(format("1899-12-31 00:00:00"; "yyyy-mm-dd hh:mm:ss");Table_name'[TIME]; minute)/60

Using this formula I am getting those hours over 24:00:00 converted into decimal numbers, which also fits me. 

Greg_Deckler
Super User
Super User

You can bring it in as text and then I would recommend these two links:

 

https://community.powerbi.com/t5/Community-Blog/Aggregating-Duration-Time/ba-p/22486

https://community.powerbi.com/t5/Quick-Measures-Gallery/Chelsie-Eiden-s-Duration/td-p/793639


@ me in replies or I'll lose your thread!!!
Instead of a Kudo, please vote for this idea
Become an expert!: Enterprise DNA
External Tools: MSHGQM
YouTube Channel!: Microsoft Hates Greg
Latest book!:
The Definitive Guide to Power Query (M)

DAX is easy, CALCULATE makes DAX hard...

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.