March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount! Early bird discount ends December 31.
Register NowBe one of the first to start using Fabric Databases. View on-demand sessions with database experts and the Microsoft product team to learn just how easy it is to get started. Watch now
Hi,
I have the following Input table(see pic below) and I'd like to have it in the format shown in Output table. How do I parse the column FruitsQuantity taking into account there can the N occurences(\Fruit\Quantity) per person.
Thanks!
Solved! Go to Solution.
Hello @Cami
check out this solution. It's dynamically
let
Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("LYy9CoAgGEXf5ZsdUqvdKQgChzavg4RU4B9G759Iyx3OOVxjiBOjPce2gColeGAEtHcVmMgyQ6I5Fe7D90aHNwJ86Eo2tOYrdbNUV/wDCGBz6czA/F82KMnaDw==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [ID = _t, Name = _t, FruitsQuantity = _t]),
#"Changed Type" = Table.TransformColumnTypes(Source,{{"ID", Int64.Type}, {"Name", type text}, {"FruitsQuantity", type text}}),
TransformTextWIthSplitterToTable = Table.TransformColumns
(
#"Changed Type",
{
{
"FruitsQuantity",
each Table.FromRecords(List.Transform(List.Split(Text.SplitAny(Text.End(_,Text.Length(_)-1),"\"),2), each [Fruit= _{0}, Quantity= _{1}]))
}
}
),
Expand = Table.ExpandTableColumn(TransformTextWIthSplitterToTable, "FruitsQuantity", {"Fruit", "Quantity"}, {"Fruit", "Quantity"})
in
Expand
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
t
let
Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("HYtLCoAgEIbvMms3RhGdxd/FOIgFPgal+ze0/R4hEDOTI1atGdiBluvowEHRBUopmdT6NpN++5mIGCuT9c4LOG3hXgZwAZrnesRSTzF+", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [name = _t, #"fr/qty" = _t]),
#"Added Custom" = Table.AddColumn(Source, "Custom", each let lst=Text.Split([#"fr/qty"],"\") in List.Zip({List.Alternate(lst,1,1,1),List.Alternate(lst,1,1,0)})),
#"Expanded Custom" = Table.ExpandListColumn(#"Added Custom", "Custom"),
#"Extracted Values" = Table.TransformColumns(#"Expanded Custom", {"Custom", each Text.Combine(List.Transform(_, Text.From), ";"), type text}),
#"Split Column by Delimiter" = Table.SplitColumn(#"Extracted Values", "Custom", Splitter.SplitTextByDelimiter(";", QuoteStyle.Csv), {"Custom.1", "Custom.2"})
in
#"Split Column by Delimiter"
ry also this:
another way
let
Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("HYtLCoAgEIbvMms3RhGdxd/FOIgFPgal+ze0/R4hEDOTI1atGdiBluvowEHRBUopmdT6NpN++5mIGCuT9c4LOG3hXgZwAZrnesRSTzF+", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [name = _t, #"fr/qty" = _t]),
#"Added Custom1" = Table.AddColumn(Source, "Custom.1", each Splitter.SplitTextByCharacterTransition( {"0".."9"},{"\"})([#"fr/qty"])),
#"Expanded Custom.1" = Table.ExpandListColumn(#"Added Custom1", "Custom.1"),
#"Split Column by Character Transition" = Table.SplitColumn(#"Expanded Custom.1", "Custom.1", Splitter.SplitTextByCharacterTransition({"\"}, {"0".."9"}), {"fruits", "quantity"}),
#"Replaced Value" = Table.ReplaceValue(#"Split Column by Character Transition","\","",Replacer.ReplaceText,{"fruits"})
in
#"Replaced Value"
Hello @Cami
check out this solution. It's dynamically
let
Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("LYy9CoAgGEXf5ZsdUqvdKQgChzavg4RU4B9G759Iyx3OOVxjiBOjPce2gColeGAEtHcVmMgyQ6I5Fe7D90aHNwJ86Eo2tOYrdbNUV/wDCGBz6czA/F82KMnaDw==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [ID = _t, Name = _t, FruitsQuantity = _t]),
#"Changed Type" = Table.TransformColumnTypes(Source,{{"ID", Int64.Type}, {"Name", type text}, {"FruitsQuantity", type text}}),
TransformTextWIthSplitterToTable = Table.TransformColumns
(
#"Changed Type",
{
{
"FruitsQuantity",
each Table.FromRecords(List.Transform(List.Split(Text.SplitAny(Text.End(_,Text.Length(_)-1),"\"),2), each [Fruit= _{0}, Quantity= _{1}]))
}
}
),
Expand = Table.ExpandTableColumn(TransformTextWIthSplitterToTable, "FruitsQuantity", {"Fruit", "Quantity"}, {"Fruit", "Quantity"})
in
Expand
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
This very much solves my problem.
Great approach, thanks a lot!
@Cami Well, first you would Split by Delimiter:
After that, probably an unpivot and then you do something where you number each row 1 and 2 and do some fancy stuff. @ImkeF @edhans
Thank you for your quick response!
This does not solve my problem. I need the solution to be dynamic. Split by Delimiter takes into account the maximum number of occurences of the given delimiter from the column and proposes the number of columns to split to. In an environment I could have 6 occurences and in another 10.
March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount!
Your insights matter. That’s why we created a quick survey to learn about your experience finding answers to technical questions.
Arun Ulag shares exciting details about the Microsoft Fabric Conference 2025, which will be held in Las Vegas, NV.