cancel
Showing results for 
Search instead for 
Did you mean: 
Reply
New Member

splitting a cell with multiple entries

StateFruit

Quantity

California

Apple

Pear

Grapes

12

15

30

I have this huge problem I inherited 😞

There are multiple entries in a cell and I would like to give each line within the fruit cell its own row so I can sum up the quantities.

I'm sure this is already solved. Can someone share the link to this solution? 😞

1 ACCEPTED SOLUTION
Community Support
Community Support

Hi, @jjvaca1972 

 

Based on your description, I created data to reproduce your scenario.The pbix file is attached in the end.

Table:

h1.png

 

Here are the m codes for transformations in 'Advanced Editor'.

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45Wck7MyUzLL8rLTFTSUXIsKMhJjckLSE0sislzL0osSC0GihoaxeQZmsbkGRsoxcYCAA==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [State = _t, Fruit = _t, Quantity = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"State", type text}, {"Fruit", type text}, {"Quantity", type text}}),
    Custom1 = Table.TransformColumns(#"Changed Type",{{"Fruit",each Text.Split(_,"#(lf)")},{"Quantity",each Text.Split(_,"#(lf)")}}),
    #"Added Custom" = Table.AddColumn(Custom1, "Custom", each let f=[Fruit] in
List.Generate(
    ()=>0,
    each _<=List.Count(f)-1,
    each _+1
)),
    #"Expanded Custom" = Table.ExpandListColumn(#"Added Custom", "Custom"),
    #"Added Custom1" = Table.AddColumn(#"Expanded Custom", "NewFruit", each [Fruit]{[Custom]}),
    #"Added Custom2" = Table.AddColumn(#"Added Custom1", "NewQuantity", each [Quantity]{[Custom]}),
    #"Removed Columns" = Table.RemoveColumns(#"Added Custom2",{"Fruit", "Quantity", "Custom"})
in
    #"Removed Columns"

 

Result:

h2.png

 

Best Regards

Allan

 

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

3 REPLIES 3
Community Support
Community Support

Hi, @jjvaca1972 

 

Based on your description, I created data to reproduce your scenario.The pbix file is attached in the end.

Table:

h1.png

 

Here are the m codes for transformations in 'Advanced Editor'.

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45Wck7MyUzLL8rLTFTSUXIsKMhJjckLSE0sislzL0osSC0GihoaxeQZmsbkGRsoxcYCAA==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [State = _t, Fruit = _t, Quantity = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"State", type text}, {"Fruit", type text}, {"Quantity", type text}}),
    Custom1 = Table.TransformColumns(#"Changed Type",{{"Fruit",each Text.Split(_,"#(lf)")},{"Quantity",each Text.Split(_,"#(lf)")}}),
    #"Added Custom" = Table.AddColumn(Custom1, "Custom", each let f=[Fruit] in
List.Generate(
    ()=>0,
    each _<=List.Count(f)-1,
    each _+1
)),
    #"Expanded Custom" = Table.ExpandListColumn(#"Added Custom", "Custom"),
    #"Added Custom1" = Table.AddColumn(#"Expanded Custom", "NewFruit", each [Fruit]{[Custom]}),
    #"Added Custom2" = Table.AddColumn(#"Added Custom1", "NewQuantity", each [Quantity]{[Custom]}),
    #"Removed Columns" = Table.RemoveColumns(#"Added Custom2",{"Fruit", "Quantity", "Custom"})
in
    #"Removed Columns"

 

Result:

h2.png

 

Best Regards

Allan

 

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

Super User II
Super User II
Super User III
Super User III

Hi @jjvaca1972 

Can you share some source data in a file please?  It's not clear whether the data as shown are in merged cells or what the delimiter is between words and values.  Spaces?

Phil


If I answered your question please mark my post as the solution.

If my answer helped solve your problem, give it a kudos by clicking on the Thumbs Up.



Did I answer your question? Then please mark my post as the solution.
If I helped you, click on the Thumbs Up to give Kudos.


Blog :: YouTube Channel :: Connect on Linkedin


Proud to be a Super User!


Helpful resources

Announcements
secondImage

Congratulations!

We are excited to announce the Power BI Super Users!

Microsoft Ignite

Microsoft Ignite

Join digitally, March 2–4, 2021 to explore new tech that's ready to implement. Experience the keynote in mixed reality through AltspaceVR!

secondImage

The largest Power BI virtual conference

100+ sessions, 100+ speakers, Product managers, MVPs, and experts. All about Power BI. Attend online or watch the recordings.

Top Solution Authors
Top Kudoed Authors