Skip to main content
cancel
Showing results for 
Search instead for 
Did you mean: 

Earn a 50% discount on the DP-600 certification exam by completing the Fabric 30 Days to Learn It challenge.

Reply
simonmcd
Frequent Visitor

Transforming headers and data that is across multiple rows

I'm struggling to tranform a table that was scraped from a website. The headers and data run across two rows so need to shift row 3 to the end of row 1 and row 4 to the end of row 2. I thought of creating using M-Code to create two tables from this table (one with rows 1&2 and another with 3&4) then combining them but didn't think it was an efficient way of doing this? Any help would be greatly appreciated! 

simonmcd_0-1626179270933.png

 

1 ACCEPTED SOLUTION

@simonmcd 

Hi , this shoudl work for you. past eht ecode on a new blank query and check the steps.

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WCijKTE5V0oHQCs4ZiXnpqQqqQAGnzBQg6Z+WlloEogtS85RidaKVDIEcIyA2BmITIDYFi/omFmWnlgC5wRmJRanFIO2pJYlAyrUAxHEBkiBlZkC2ORBbALElEBsaKMXGAgA=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Column1 = _t, Column2 = _t, Column3 = _t, Column4 = _t, Column5 = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Column1", type text}, {"Column2", type text}, {"Column3", type text}, {"Column4", type text}, {"Column5", type text}}),
    #"Added Index" = Table.AddIndexColumn(#"Changed Type", "Index", 1, 1, Int64.Type),
    #"Calculated Modulo" = Table.TransformColumns(#"Added Index", {{"Index", each Number.Mod(_, 2), type number}}),
    Custom1 = #"Calculated Modulo",
    #"Kept Last Rows" = Table.PromoteHeaders(Table.LastN(Custom1, 2)),
    #"Kept First Rows" = Table.PromoteHeaders(Table.FirstN(Custom1,2)),
    #"Merged Queries" = Table.NestedJoin(#"Kept First Rows", {"1"}, #"Kept Last Rows", {"1"}, "Kept First Rows", JoinKind.LeftOuter),
    #"Expanded Kept First Rows" = Table.ExpandTableColumn(#"Merged Queries", "Kept First Rows", {"Market", "Shares", "Beta", "Eps", "Dps"}, {"Market", "Shares", "Beta", "Eps", "Dps"}),
    #"Removed Columns" = Table.RemoveColumns(#"Expanded Kept First Rows",{"1"})
in
    #"Removed Columns"


Data:

Fowmy_0-1626182798359.png


Result:

Fowmy_1-1626182824783.png

 

 

Did I answer your question? Mark my post as a solution! and hit thumbs up


Subscribe and learn Power BI from these videos

Website LinkedIn PBI User Group

View solution in original post

4 REPLIES 4
Fowmy
Super User
Super User

@simonmcd 

Please confirm if your dataset has only four rows at the beginning as you have shown here. or you have multiple sets 

Did I answer your question? Mark my post as a solution! and hit thumbs up


Subscribe and learn Power BI from these videos

Website LinkedIn PBI User Group

Thanks for the reply. There are only 4 rows of data, the table is fixed and won't expand from what you can see on the screen shot. Only the data inside the table will change over time.

@simonmcd 

Hi , this shoudl work for you. past eht ecode on a new blank query and check the steps.

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WCijKTE5V0oHQCs4ZiXnpqQqqQAGnzBQg6Z+WlloEogtS85RidaKVDIEcIyA2BmITIDYFi/omFmWnlgC5wRmJRanFIO2pJYlAyrUAxHEBkiBlZkC2ORBbALElEBsaKMXGAgA=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Column1 = _t, Column2 = _t, Column3 = _t, Column4 = _t, Column5 = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Column1", type text}, {"Column2", type text}, {"Column3", type text}, {"Column4", type text}, {"Column5", type text}}),
    #"Added Index" = Table.AddIndexColumn(#"Changed Type", "Index", 1, 1, Int64.Type),
    #"Calculated Modulo" = Table.TransformColumns(#"Added Index", {{"Index", each Number.Mod(_, 2), type number}}),
    Custom1 = #"Calculated Modulo",
    #"Kept Last Rows" = Table.PromoteHeaders(Table.LastN(Custom1, 2)),
    #"Kept First Rows" = Table.PromoteHeaders(Table.FirstN(Custom1,2)),
    #"Merged Queries" = Table.NestedJoin(#"Kept First Rows", {"1"}, #"Kept Last Rows", {"1"}, "Kept First Rows", JoinKind.LeftOuter),
    #"Expanded Kept First Rows" = Table.ExpandTableColumn(#"Merged Queries", "Kept First Rows", {"Market", "Shares", "Beta", "Eps", "Dps"}, {"Market", "Shares", "Beta", "Eps", "Dps"}),
    #"Removed Columns" = Table.RemoveColumns(#"Expanded Kept First Rows",{"1"})
in
    #"Removed Columns"


Data:

Fowmy_0-1626182798359.png


Result:

Fowmy_1-1626182824783.png

 

 

Did I answer your question? Mark my post as a solution! and hit thumbs up


Subscribe and learn Power BI from these videos

Website LinkedIn PBI User Group

That works beautifully! Thanks. I had a funny feeling it would be really complicated : )

Helpful resources

Announcements
RTI Forums Carousel3

New forum boards available in Real-Time Intelligence.

Ask questions in Eventhouse and KQL, Eventstream, and Reflex.

LearnSurvey

Fabric certifications survey

Certification feedback opportunity for the community.

Top Solution Authors
Top Kudoed Authors