Power BI is turning 10, and we’re marking the occasion with a special community challenge. Use your creativity to tell a story, uncover trends, or highlight something unexpected.
Get startedJoin us for an expert-led overview of the tools and concepts you'll need to become a Certified Power BI Data Analyst and pass exam PL-300. Register now.
1;;ch=13;;rw=4.9;;rl=8;;rh=3.8;;tk=tapered;;tw=1.2;;tt=1.9;;md=Room%20Kit%20EQ;;dc=Dark;;dm=wall;;ss=75;;sc=2;;bs=0;;mc=4;;mt=Table%20Mic%20Pro;;mp=webex |
1;;ch=16;;rw=6;;rl=9;;rh=3;;tk=ushape;;tw=3;;md=EQX;;dc=Dark;;dm=wall;;ss=80;;sc=2;;bs=0;;mc=2;;mt=Ceiling%20Mic;;mp=webex |
1;;ch=4;;rw=3.7;;rl=3.5;;rh=2.4;;tk=tapered;;tw=1;;tt=0.5;;md=Room%20Bar;;dc=Dark;;dm=wall;;ss=55;;sc=1;;bs=0;;mc=1;;mt=None;;mp=webex |
1;;ch=17;;rw=7;;rl=11;;rh=4;;tk=regular;;tw=1.8;;md=Room%20Kit%20Pro;;dc=Dark;;dm=wall;;ss=75;;sc=2;;bs=0;;mc=4;;mt=Table%20Mic%20Pro;;mp=webex |
Hi,
As you can see the categories & values in each cell are not in a consistent order. I would like to split this primary column into multiple category columns (ch, rw,rl,tk, etc) along with their respective value. Need to add null wherever the category is not present.
Solved! Go to Solution.
let
Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("rdHBisIwEAbgdxG8SWia1lbCXHQ9LbuoeFgQD2ka2mJqJY10H3/HCehC9eZlJoSE+fjncJhwKXUNXEjpBkjYAruFHGsNgmH3J/DqYpwp8TwAZzF2jx1ftiXsuq6dxtFn47Gut1KWGj6UO+GhhUFZK2XfQ5Zi04Bfix4i/Kghwephrwpr8OdXo7FuXIe3FxhMYX4nx9ldNyfdnGyLYCPZta/RRjBBnPX25wUhj0aEmAgr09jmXAXE0/EJTRcso/mCpSSIWTJOh7KJbi8e2SyVe2FKQyz8n4mT6bs7m+dJZGQJEs4JEhjOVFd7m0RLysfLoXDfuJ3jHw==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Column1 = _t]),
#"Added Index" = Table.AddIndexColumn(Source, "Index", 0, 1, Int64.Type),
#"Split Column by Delimiter" = Table.ExpandListColumn(Table.TransformColumns(#"Added Index", {{"Column1", Splitter.SplitTextByDelimiter(";", QuoteStyle.Csv), let itemType = (type nullable text) meta [Serialized.Text = true] in type {itemType}}}), "Column1"),
#"Filtered Rows" = Table.SelectRows(#"Split Column by Delimiter", each ([Column1] <> "" and [Column1] <> "1")),
#"Split Column by Delimiter1" = Table.SplitColumn(#"Filtered Rows", "Column1", Splitter.SplitTextByEachDelimiter({"="}, QuoteStyle.Csv, false), {"Attribute", "Value"}),
#"Pivoted Column" = Table.Pivot(#"Split Column by Delimiter1", List.Distinct(#"Split Column by Delimiter1"[Attribute]), "Attribute", "Value")
in
#"Pivoted Column"
How to use this code: Create a new Blank Query. Click on "Advanced Editor". Replace the code in the window with the code provided here. Click "Done". Once you examined the code, replace the Source step with your own source.
let
Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("rdHBisIwEAbgdxG8SWia1lbCXHQ9LbuoeFgQD2ka2mJqJY10H3/HCehC9eZlJoSE+fjncJhwKXUNXEjpBkjYAruFHGsNgmH3J/DqYpwp8TwAZzF2jx1ftiXsuq6dxtFn47Gut1KWGj6UO+GhhUFZK2XfQ5Zi04Bfix4i/Kghwephrwpr8OdXo7FuXIe3FxhMYX4nx9ldNyfdnGyLYCPZta/RRjBBnPX25wUhj0aEmAgr09jmXAXE0/EJTRcso/mCpSSIWTJOh7KJbi8e2SyVe2FKQyz8n4mT6bs7m+dJZGQJEs4JEhjOVFd7m0RLysfLoXDfuJ3jHw==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Column1 = _t]),
#"Added Index" = Table.AddIndexColumn(Source, "Index", 0, 1, Int64.Type),
#"Split Column by Delimiter" = Table.ExpandListColumn(Table.TransformColumns(#"Added Index", {{"Column1", Splitter.SplitTextByDelimiter(";", QuoteStyle.Csv), let itemType = (type nullable text) meta [Serialized.Text = true] in type {itemType}}}), "Column1"),
#"Filtered Rows" = Table.SelectRows(#"Split Column by Delimiter", each ([Column1] <> "" and [Column1] <> "1")),
#"Split Column by Delimiter1" = Table.SplitColumn(#"Filtered Rows", "Column1", Splitter.SplitTextByEachDelimiter({"="}, QuoteStyle.Csv, false), {"Attribute", "Value"}),
#"Pivoted Column" = Table.Pivot(#"Split Column by Delimiter1", List.Distinct(#"Split Column by Delimiter1"[Attribute]), "Attribute", "Value")
in
#"Pivoted Column"
How to use this code: Create a new Blank Query. Click on "Advanced Editor". Replace the code in the window with the code provided here. Click "Done". Once you examined the code, replace the Source step with your own source.
Hi,
Based on the data that you have shared, show the expected result very clearly.
This is your chance to engage directly with the engineering team behind Fabric and Power BI. Share your experiences and shape the future.
Check out the June 2025 Power BI update to learn about new features.
User | Count |
---|---|
72 | |
68 | |
53 | |
39 | |
33 |
User | Count |
---|---|
71 | |
63 | |
57 | |
49 | |
46 |