Find everything you need to get certified on Fabric—skills challenges, live sessions, exam prep, role guidance, and more. Get started
Dear all,
I have some data in format of block of rows. Is there any idea on how to transform this kind of data into table ?
See attached picture for demonstration.
Thank you,
madrid
Solved! Go to Solution.
If the rows will always be in groups of four, you can
let
Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45W8kvMTVXSUXJ0dFSK1YlWcs1NzMwB8lNBtKFDcn5uQWJepR6QBks7poMUGxuAOSGZJTkgbnAikAIJQM1ycnLCNMsIh1lGpihmeYYgm+Ts7IxpkjEuVxmimOSbmJeYnlqkFBsLAA==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Column1 = _t, Column2 = _t]),
#"Changed Type" = Table.TransformColumnTypes(Source,{{"Column1", type text}, {"Column2", type text}}),
#"Added Index" = Table.AddIndexColumn(#"Changed Type", "Index", 0, 1, Int64.Type),
#"Integer-Divided Column" = Table.TransformColumns(#"Added Index", {{"Index", each Number.IntegerDivide(_, 4), Int64.Type}}),
#"Pivoted Column" = Table.Pivot(#"Integer-Divided Column", List.Distinct(#"Integer-Divided Column"[Column1]), "Column1", "Column2"),
#"Removed Columns" = Table.RemoveColumns(#"Pivoted Column",{"Index"})
in
#"Removed Columns"
The above code assumes each block has four rows. If the numbers of rows might vary, but, for example, the first row is always "Name", then you can still assign a unique number to each block with the code below, and then do your pivot as before.
#"Added Index" = Table.AddIndexColumn(#"Changed Type", "Index", 0, 1, Int64.Type),
#"Added Custom" = Table.AddColumn(#"Added Index", "Custom", each if [Column1] = "Name" then [Index] else null),
#"Removed Columns" = Table.RemoveColumns(#"Added Custom",{"Index"}),
#"Filled Down" = Table.FillDown(#"Removed Columns",{"Custom"}),
If the rows will always be in groups of four, you can
let
Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45W8kvMTVXSUXJ0dFSK1YlWcs1NzMwB8lNBtKFDcn5uQWJepR6QBks7poMUGxuAOSGZJTkgbnAikAIJQM1ycnLCNMsIh1lGpihmeYYgm+Ts7IxpkjEuVxmimOSbmJeYnlqkFBsLAA==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Column1 = _t, Column2 = _t]),
#"Changed Type" = Table.TransformColumnTypes(Source,{{"Column1", type text}, {"Column2", type text}}),
#"Added Index" = Table.AddIndexColumn(#"Changed Type", "Index", 0, 1, Int64.Type),
#"Integer-Divided Column" = Table.TransformColumns(#"Added Index", {{"Index", each Number.IntegerDivide(_, 4), Int64.Type}}),
#"Pivoted Column" = Table.Pivot(#"Integer-Divided Column", List.Distinct(#"Integer-Divided Column"[Column1]), "Column1", "Column2"),
#"Removed Columns" = Table.RemoveColumns(#"Pivoted Column",{"Index"})
in
#"Removed Columns"
The above code assumes each block has four rows. If the numbers of rows might vary, but, for example, the first row is always "Name", then you can still assign a unique number to each block with the code below, and then do your pivot as before.
#"Added Index" = Table.AddIndexColumn(#"Changed Type", "Index", 0, 1, Int64.Type),
#"Added Custom" = Table.AddColumn(#"Added Index", "Custom", each if [Column1] = "Name" then [Index] else null),
#"Removed Columns" = Table.RemoveColumns(#"Added Custom",{"Index"}),
#"Filled Down" = Table.FillDown(#"Removed Columns",{"Custom"}),
Fantastic! I was able to replicate these steps and achieve the result.
Huge thanks!
Are there always going to be four rows in a block?
yes, it is.
Check out the September 2024 Power BI update to learn about new features.
Learn from experts, get hands-on experience, and win awesome prizes.
User | Count |
---|---|
41 | |
23 | |
20 | |
20 | |
13 |
User | Count |
---|---|
157 | |
61 | |
60 | |
28 | |
20 |