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
rajulshah
Super User
Super User

Expand rows into intermediate time values

Hello everyone,

 

This is what my actual data look like:

IdStart TimeEnd Time
108:0008:34
203:1205:27

 

And this is what I want the table as below:

IdStart TimeEnd Time
108:0008:34
203:1204:00
204:0005:00
205:0005:27

 

Any help would be great! Thanks.

1 ACCEPTED SOLUTION
ImkeF
Super User
Super User

Hi @rajulshah ,

you can do this in the query editor like so: 

 

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WMlTSUTKwsDIwgNDGJkqxOtFKRiCesZUhmDa1MjJXio0FAA==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type text) meta [Serialized.Text = true]) in type table [Id = _t, #"Start Time" = _t, #"End Time" = _t]),
    CreateListOfFullHours = Table.AddColumn(Source, "AllFullHours", each { Number.From(Text.BeforeDelimiter([Start Time], ":")) .. Number.From(Text.BeforeDelimiter([End Time], ":")) }),
    TransformListOfFullHoursAndSkipFirstHour = Table.AddColumn(CreateListOfFullHours, "SkipFirstHour", each List.Transform(List.Skip([AllFullHours]), each Text.PadStart(Text.From(_), 2, "0") & ":00")),
    CreateNewTable = Table.AddColumn(TransformListOfFullHoursAndSkipFirstHour, "Result", each Table.FromColumns( { {[Start Time]} & [SkipFirstHour], [SkipFirstHour] & {[End Time] } }, { "Start Time", "End Time" } )),
    Cleanup = Table.RemoveColumns(CreateNewTable,{"Start Time", "End Time", "AllFullHours", "SkipFirstHour"}),
    #"Expanded Result" = Table.ExpandTableColumn(Cleanup, "Result", {"Start Time", "End Time"}, {"Start Time", "End Time"})
in
    #"Expanded Result"

 

Simply paste this code into the advanced editor and follow the steps.

 

Imke Feldmann (The BIccountant)

If you liked my solution, please give it a thumbs up. And if I did answer your question, please mark this post as a solution. Thanks!

How to integrate M-code into your solution -- How to get your questions answered quickly -- How to provide sample data -- Check out more PBI- learning resources here -- Performance Tipps for M-queries

View solution in original post

2 REPLIES 2
amitchandak
Super User
Super User

Create an hourly period table.

Then Create a new table like this. If this give period span correctly , then you can use logic to put correct start and end time for each period.

 

summarize(filter(table,(table[start]<=min(period[start_period]) || table[end] >=max(period[end_period])))
,table[start],table[end],period[start_period],period[end_period],table[id])

 

Appreciate your Kudos. In case, this is the solution you are looking for, mark it as the Solution. In case it does not help, please provide additional information and mark me with @
Thanks. My Recent Blog -
Winner-Topper-on-Map-How-to-Color-States-on-a-Map-with-Winners , HR-Analytics-Active-Employee-Hire-and-Termination-trend
Power-BI-Working-with-Non-Standard-Time-Periods And Comparing-Data-Across-Date-Ranges

Connect on Linkedin

ImkeF
Super User
Super User

Hi @rajulshah ,

you can do this in the query editor like so: 

 

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WMlTSUTKwsDIwgNDGJkqxOtFKRiCesZUhmDa1MjJXio0FAA==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type text) meta [Serialized.Text = true]) in type table [Id = _t, #"Start Time" = _t, #"End Time" = _t]),
    CreateListOfFullHours = Table.AddColumn(Source, "AllFullHours", each { Number.From(Text.BeforeDelimiter([Start Time], ":")) .. Number.From(Text.BeforeDelimiter([End Time], ":")) }),
    TransformListOfFullHoursAndSkipFirstHour = Table.AddColumn(CreateListOfFullHours, "SkipFirstHour", each List.Transform(List.Skip([AllFullHours]), each Text.PadStart(Text.From(_), 2, "0") & ":00")),
    CreateNewTable = Table.AddColumn(TransformListOfFullHoursAndSkipFirstHour, "Result", each Table.FromColumns( { {[Start Time]} & [SkipFirstHour], [SkipFirstHour] & {[End Time] } }, { "Start Time", "End Time" } )),
    Cleanup = Table.RemoveColumns(CreateNewTable,{"Start Time", "End Time", "AllFullHours", "SkipFirstHour"}),
    #"Expanded Result" = Table.ExpandTableColumn(Cleanup, "Result", {"Start Time", "End Time"}, {"Start Time", "End Time"})
in
    #"Expanded Result"

 

Simply paste this code into the advanced editor and follow the steps.

 

Imke Feldmann (The BIccountant)

If you liked my solution, please give it a thumbs up. And if I did answer your question, please mark this post as a solution. Thanks!

How to integrate M-code into your solution -- How to get your questions answered quickly -- How to provide sample data -- Check out more PBI- learning resources here -- Performance Tipps for M-queries

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.