Share feedback directly with Fabric product managers, participate in targeted research studies and influence the Fabric roadmap.
Sign up nowGet Fabric certified for FREE! Don't miss your chance! Learn more
Hi Everyone,
I need to reorder the contents of each row into new columns based on the date within the cells and remove the date from the cell. I've included an example of the raw and transformed data below. My apologies if this question has been asked before. I have been googling for days and haven't been able to find a resolution. Any assistance is greatly appreciated.
RAW Data Export:
| Column1 | Column2 | Column3 | Column4 |
Client1 | 24/08 9 | 31/08 19 | 10/08 6 | 17/08 4 |
Client2 | 31/08 3 | 14/09 2 | 17/08 0 | 07/09 1 |
Client3 | 17/08 2 | 24/08 3 | 31/08 1 | 07/09 4 |
TRANSFORMED Data:
| 10/08 | 17/08 | 24/08 | 31/08 | 07/09 | 14/09 |
Client1 | 6 | 4 | 9 | 19 |
|
|
Client2 |
| 0 |
| 3 | 1 | 2 |
Client3 |
| 2 | 3 | 1 | 4 |
|
Thanks
Solved! Go to Solution.
Hello @campbellmurphy
some unpivoting, splitting column and pivoting again should do the trick
Here the complete code
let
Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45Wcs7JTM0rMVTSUTIy0TewULAEsowNQSxDENPQAMQ0A7HMQSwTpVgdmCYjuFJjkDxQu6WCEVylAZBlYA4SM0TSYwyXN4JbaXxoAcJSuC6gTbEA", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [#"(blank)" = _t, Column1 = _t, Column2 = _t, Column3 = _t, Column4 = _t]),
#"Unpivoted Other Columns" = Table.UnpivotOtherColumns(Source, {"(blank)"}, "Attribute", "Value"),
#"Removed Columns" = Table.RemoveColumns(#"Unpivoted Other Columns",{"Attribute"}),
#"Split Column by Delimiter" = Table.SplitColumn(#"Removed Columns", "Value", Splitter.SplitTextByEachDelimiter({" "}, QuoteStyle.Csv, true), {"Value.1", "Value.2"}),
#"Changed Type" = Table.TransformColumnTypes(#"Split Column by Delimiter",{{"(blank)", type text}, {"Value.1", type date}, {"Value.2", Int64.Type}}),
#"Pivoted Column" = Table.Pivot(Table.TransformColumnTypes(#"Changed Type", {{"Value.1", type text}}, "de-DE"), List.Distinct(Table.TransformColumnTypes(#"Changed Type", {{"Value.1", type text}}, "de-DE")[Value.1]), "Value.1", "Value.2", List.Sum)
in
#"Pivoted Column"
Copy paste this code to the advanced editor in a new blank query to see how the solution works.
If this post helps or solves your problem, please mark it as solution (to help other users find useful content and to acknowledge the work of users that helped you)
Kudoes are nice too
Have fun
Jimmy
Hello @campbellmurphy
some unpivoting, splitting column and pivoting again should do the trick
Here the complete code
let
Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45Wcs7JTM0rMVTSUTIy0TewULAEsowNQSxDENPQAMQ0A7HMQSwTpVgdmCYjuFJjkDxQu6WCEVylAZBlYA4SM0TSYwyXN4JbaXxoAcJSuC6gTbEA", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [#"(blank)" = _t, Column1 = _t, Column2 = _t, Column3 = _t, Column4 = _t]),
#"Unpivoted Other Columns" = Table.UnpivotOtherColumns(Source, {"(blank)"}, "Attribute", "Value"),
#"Removed Columns" = Table.RemoveColumns(#"Unpivoted Other Columns",{"Attribute"}),
#"Split Column by Delimiter" = Table.SplitColumn(#"Removed Columns", "Value", Splitter.SplitTextByEachDelimiter({" "}, QuoteStyle.Csv, true), {"Value.1", "Value.2"}),
#"Changed Type" = Table.TransformColumnTypes(#"Split Column by Delimiter",{{"(blank)", type text}, {"Value.1", type date}, {"Value.2", Int64.Type}}),
#"Pivoted Column" = Table.Pivot(Table.TransformColumnTypes(#"Changed Type", {{"Value.1", type text}}, "de-DE"), List.Distinct(Table.TransformColumnTypes(#"Changed Type", {{"Value.1", type text}}, "de-DE")[Value.1]), "Value.1", "Value.2", List.Sum)
in
#"Pivoted Column"
Copy paste this code to the advanced editor in a new blank query to see how the solution works.
If this post helps or solves your problem, please mark it as solution (to help other users find useful content and to acknowledge the work of users that helped you)
Kudoes are nice too
Have fun
Jimmy
Share feedback directly with Fabric product managers, participate in targeted research studies and influence the Fabric roadmap.
If you love stickers, then you will definitely want to check out our Community Sticker Challenge!
Check out the January 2026 Power BI update to learn about new features.
| User | Count |
|---|---|
| 12 | |
| 11 | |
| 11 | |
| 7 | |
| 6 |