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

Enhance your career with this limited time 50% discount on Fabric and Power BI exams. Ends August 31st. Request your voucher.

Reply
jzy5282
Regular Visitor

How do you split a table of IDs and Concatenated Strings into a normalized table?

 Each concatString shows (Value, Year, Status, RowID)  with a pipe separator.  How to split and transpose so it shows 4 columns: RowID, Value, Year, Status?

 

Table Values [ID], [concatString]

8390.00|2021|false|839|35,000.00|2022|true|839|35,000.00|2023|true|839|35,000.00|2024|true|839|35,000.00|2025|true|839|35,000.00|2026|true|839|0.00|2027|false|839|
8400|2014|TRUE|840|0|2015|TRUE|840|0|2016|TRUE|840|0|2017|TRUE|840|0|2018|TRUE|840|0|2019|TRUE|840|0|2020|TRUE|840|12500|2021|TRUE|840|12500|2022|TRUE|840|12500|2023|FALSE|840|12500|2024|FALSE|840|12500|2025|FALSE|840|12500|2026|FALSE|840|
8410|2014|TRUE|841|15000|2015|TRUE|841|15000|2016|TRUE|841|15000|2017|TRUE|841|15000|2018|TRUE|841|15000|2019|TRUE|841|0|2020|TRUE|841|0|2021|TRUE|841|0|2022|TRUE|841|0|2023|FALSE|841|0|2024|FALSE|841|0|2025|FALSE|841|0|2026|FALSE|841|
8450.00|2020|false|845|0|2021|TRUE|845|40000|2022|TRUE|845|40000|2023|FALSE|845|40000|2024|FALSE|845|40000|2025|FALSE|845|40000|2026|FALSE|845|0.00|2027|false|845|
1 ACCEPTED SOLUTION
v-kkf-msft
Community Support
Community Support

Hi @jzy5282 ,

 

Split [concatString] column into list by the separator "|".
Split this list into smaller lists every 4.
Expand the list into rows and columns.

 

Please try the query.

 

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("ddItE8IwDAbg/1K949Iu6TaJAIXiQ+0mEKBQfLj8eArXXrMsk+/TijdtxtH17eAaBxsADhA836+P142TcksNQDkI/H5+DG9XHFecVjxWL9SJLm5qUlWEX9V05pHPx8uOk/A/k8pR5U7lXuVhngPU7AOVt1laMKzl/fZwUogWkoVRYB7bL8b27NP1+ejComGdYb1hQ7X5U+TsVQ4q1/EzoAbSEAXkkUksJZRFQFIViBFA/YSwWkUgWkgWRoGLpUzmpukL", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [ID = _t, concatString = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"ID", Int64.Type}, {"concatString", type text}}),
    #"Added Custom" = Table.AddColumn(#"Changed Type", "SplitToLists", each List.Split( Splitter.SplitTextByDelimiter("|")([concatString]),4)),
    #"Expanded SplitToLists" = Table.ExpandListColumn(#"Added Custom", "SplitToLists"),
    #"Extracted Values" = Table.TransformColumns(#"Expanded SplitToLists", {"SplitToLists", each Text.Combine(List.Transform(_, Text.From), ";"), type text}),
    #"Split Column by Delimiter" = Table.SplitColumn(#"Extracted Values", "SplitToLists", Splitter.SplitTextByDelimiter(";", QuoteStyle.Csv), {"Value", "Year", "Status", "RowID"}),
    #"Changed Type1" = Table.TransformColumnTypes(#"Split Column by Delimiter",{{"Value", Int64.Type}, {"Year", Int64.Type}, {"Status", type logical}, {"RowID", Int64.Type}})
in
    #"Changed Type1"

vkkfmsft_0-1658460217135.png

 

If the problem is still not resolved, please provide detailed error information or the expected result you expect. Let me know immediately, looking forward to your reply.
Best Regards,
Winniz
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

View solution in original post

1 REPLY 1
v-kkf-msft
Community Support
Community Support

Hi @jzy5282 ,

 

Split [concatString] column into list by the separator "|".
Split this list into smaller lists every 4.
Expand the list into rows and columns.

 

Please try the query.

 

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("ddItE8IwDAbg/1K949Iu6TaJAIXiQ+0mEKBQfLj8eArXXrMsk+/TijdtxtH17eAaBxsADhA836+P142TcksNQDkI/H5+DG9XHFecVjxWL9SJLm5qUlWEX9V05pHPx8uOk/A/k8pR5U7lXuVhngPU7AOVt1laMKzl/fZwUogWkoVRYB7bL8b27NP1+ejComGdYb1hQ7X5U+TsVQ4q1/EzoAbSEAXkkUksJZRFQFIViBFA/YSwWkUgWkgWRoGLpUzmpukL", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [ID = _t, concatString = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"ID", Int64.Type}, {"concatString", type text}}),
    #"Added Custom" = Table.AddColumn(#"Changed Type", "SplitToLists", each List.Split( Splitter.SplitTextByDelimiter("|")([concatString]),4)),
    #"Expanded SplitToLists" = Table.ExpandListColumn(#"Added Custom", "SplitToLists"),
    #"Extracted Values" = Table.TransformColumns(#"Expanded SplitToLists", {"SplitToLists", each Text.Combine(List.Transform(_, Text.From), ";"), type text}),
    #"Split Column by Delimiter" = Table.SplitColumn(#"Extracted Values", "SplitToLists", Splitter.SplitTextByDelimiter(";", QuoteStyle.Csv), {"Value", "Year", "Status", "RowID"}),
    #"Changed Type1" = Table.TransformColumnTypes(#"Split Column by Delimiter",{{"Value", Int64.Type}, {"Year", Int64.Type}, {"Status", type logical}, {"RowID", Int64.Type}})
in
    #"Changed Type1"

vkkfmsft_0-1658460217135.png

 

If the problem is still not resolved, please provide detailed error information or the expected result you expect. Let me know immediately, looking forward to your reply.
Best Regards,
Winniz
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

Helpful resources

Announcements
July PBI25 Carousel

Power BI Monthly Update - July 2025

Check out the July 2025 Power BI update to learn about new features.

Join our Fabric User Panel

Join our Fabric User Panel

This is your chance to engage directly with the engineering team behind Fabric and Power BI. Share your experiences and shape the future.

June 2025 community update carousel

Fabric Community Update - June 2025

Find out what's new and trending in the Fabric community.

Top Solution Authors