cancel
Showing results for 
Search instead for 
Did you mean: 
Reply
reymalave Helper I
Helper I

handling n number of columns

Hi Guys,

 

I have this table coming from a csv. The table has trajectories over x,y,z points and start and finish instants with and index column.

Each index (trackedFaceID) has multiple (x,y,z) points with duration (start and finish instants) spread over multiple columns, I want to have only four columns ("id", "duration", "x", "y","z")

You can download trajectories csv

 
 
 

Annotation 2019-11-18 140028.png

1 ACCEPTED SOLUTION

Accepted Solutions
Microsoft artemus
Microsoft

Re: handling n number of columns

Here you go something like this:

 

let
    Source = Excel.Workbook(File.Contents("C:\Users\artemus\Downloads\trajectories.xlsx"), null, true),
    in_Sheet = Source{[Item="in",Kind="Sheet"]}[Data],
    #"Promoted Headers" = Table.PromoteHeaders(in_Sheet, [PromoteAllScalars=true]),
    #"Changed Type" = Table.TransformColumnTypes(#"Promoted Headers",{{"trajectoryId", Int64.Type}, {"trackedFaceID", Int64.Type}, {"beginInstant", type number}, {"endInstant", type number}, {"duration", Int64.Type}, {"trajectoryIntervals", type text}}),
    #"Added Custom" = Table.AddColumn(#"Changed Type", "trajectoryIntrevals_Json", each "{" & [trajectoryIntervals] & "}"),
    #"Inserted Parsed JSON" = Table.AddColumn(#"Added Custom", "JSON", each Json.Document([trajectoryIntrevals_Json])),
    #"Expanded JSON" = Table.ExpandRecordColumn(#"Inserted Parsed JSON", "JSON", {"trajectoryIntervals"}, {"trajectoryIntervals.1"}),
    #"Expanded trajectoryIntervals.1" = Table.ExpandListColumn(#"Expanded JSON", "trajectoryIntervals.1"),
    #"Expanded trajectoryIntervals.2" = Table.ExpandRecordColumn(#"Expanded trajectoryIntervals.1", "trajectoryIntervals.1", {"s", "e", "x", "y", "z"}, {"s", "e", "x", "y", "z"}),
    #"Removed Other Columns" = Table.SelectColumns(#"Expanded trajectoryIntervals.2",{"trajectoryId", "duration", "x", "y", "z"})
in
    #"Removed Other Columns"

The key is to add {} around your trajectory column so that you can parse the entries as JSON

 

View solution in original post

2 REPLIES 2
Microsoft artemus
Microsoft

Re: handling n number of columns

Here you go something like this:

 

let
    Source = Excel.Workbook(File.Contents("C:\Users\artemus\Downloads\trajectories.xlsx"), null, true),
    in_Sheet = Source{[Item="in",Kind="Sheet"]}[Data],
    #"Promoted Headers" = Table.PromoteHeaders(in_Sheet, [PromoteAllScalars=true]),
    #"Changed Type" = Table.TransformColumnTypes(#"Promoted Headers",{{"trajectoryId", Int64.Type}, {"trackedFaceID", Int64.Type}, {"beginInstant", type number}, {"endInstant", type number}, {"duration", Int64.Type}, {"trajectoryIntervals", type text}}),
    #"Added Custom" = Table.AddColumn(#"Changed Type", "trajectoryIntrevals_Json", each "{" & [trajectoryIntervals] & "}"),
    #"Inserted Parsed JSON" = Table.AddColumn(#"Added Custom", "JSON", each Json.Document([trajectoryIntrevals_Json])),
    #"Expanded JSON" = Table.ExpandRecordColumn(#"Inserted Parsed JSON", "JSON", {"trajectoryIntervals"}, {"trajectoryIntervals.1"}),
    #"Expanded trajectoryIntervals.1" = Table.ExpandListColumn(#"Expanded JSON", "trajectoryIntervals.1"),
    #"Expanded trajectoryIntervals.2" = Table.ExpandRecordColumn(#"Expanded trajectoryIntervals.1", "trajectoryIntervals.1", {"s", "e", "x", "y", "z"}, {"s", "e", "x", "y", "z"}),
    #"Removed Other Columns" = Table.SelectColumns(#"Expanded trajectoryIntervals.2",{"trajectoryId", "duration", "x", "y", "z"})
in
    #"Removed Other Columns"

The key is to add {} around your trajectory column so that you can parse the entries as JSON

 

View solution in original post

reymalave Helper I
Helper I

Re: handling n number of columns

Thanks! It worked just fine. Nice trick!

Helpful resources

Announcements
New Ranks Launched March 24th!

New Ranks Launched March 24th!

The time has come: We are finally able to share more details on the brand-new ranks coming to the Power BI Community!

‘Better Together’ Contest Finalists Announced!

‘Better Together’ Contest Finalists Announced!

Congrats to the finalists of our ‘Better Together’-themed T-shirt design contest! Click for the top entries.

Arun 'Triple A' Event Video, Q&A, and Slides

Arun 'Triple A' Event Video, Q&A, and Slides

Missed the Arun 'Triple A' event or want to revisit it? We've got you covered! Check out the video, Q&A, and slides now.

Join THE global Microsoft Power Platform event series.

Join THE global Power Platform event series.

Attend for two days of expert-led learning and innovation on topics like AI and Analytics, powered by Dynamic Communities.

Community Summit North America

Community Summit North America

Innovate, Collaborate, Grow. The top training and networking event across the globe for Microsoft Business Applications

Top Solution Authors
Top Kudoed Authors