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

Register now to learn Fabric in free live sessions led by the best Microsoft experts. From Apr 16 to May 9, in English and Spanish.

Reply
thomastatum
Frequent Visitor

Split Column by delimiter, add row but empty values

Is there a way to split a column by a delimeter and add a new row.  But when the rows are added, have the values of certain columns be empty?

 

We have the following table:

 

Team         Sales    Countries

Red           104          US

Blue          234         Italy, Spain

Green       100          Brazil

Purple       435          Germany, Poland

 

I would like the result to be:

 

Team  Sales    Countries

Red     104           US

Blue     234           Italy

Blue                     Spain

Green  100           Brazil

Purple  435           Germany

Purple                   Poland

 

Is this possible?

 

With normal split -> add row, the sales numbers are copied to the added rows and its throwing off our totals.  Any idea to change this effect?

 

Thank you,

-Thomas

1 ACCEPTED SOLUTION
Anonymous
Not applicable

@thomastatum,

You can copy and paste this code into your Advanced Editor for reference

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WCkpNUdJRMjQwAZKhwUqxOtFKTjmlqUCekTFIzLMkMadSRyG4IDEzDyzrXpSamgfWYgAknYoSqzJzwBIBpUUFOSCNJsamQNI9tSg3MQ+oNSA/JzEvRSk2FgA=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type text) meta [Serialized.Text = true]) in type table [Team = _t, Sales = _t, Countries = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Team", type text}, {"Sales", Int64.Type}, {"Countries", type text}}),
    #"Split Column by Delimiter" = Table.SplitColumn(#"Changed Type", "Countries", Splitter.SplitTextByDelimiter(", ", QuoteStyle.Csv), {"Countries.1", "Countries.2"}),
    #"Changed Type1" = Table.TransformColumnTypes(#"Split Column by Delimiter",{{"Countries.1", type text}, {"Countries.2", type text}}),
    #"Unpivoted Columns" = Table.UnpivotOtherColumns(#"Changed Type1", {"Team", "Sales"}, "Attribute", "Value"),
    #"Added Conditional Column" = Table.AddColumn(#"Unpivoted Columns", "New Sale", each if [Attribute] = "Countries.1" then [Sales] else null),
    #"Removed Columns" = Table.RemoveColumns(#"Added Conditional Column",{"Sales", "Attribute"})
in
    #"Removed Columns"

View solution in original post

1 REPLY 1
Anonymous
Not applicable

@thomastatum,

You can copy and paste this code into your Advanced Editor for reference

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WCkpNUdJRMjQwAZKhwUqxOtFKTjmlqUCekTFIzLMkMadSRyG4IDEzDyzrXpSamgfWYgAknYoSqzJzwBIBpUUFOSCNJsamQNI9tSg3MQ+oNSA/JzEvRSk2FgA=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type text) meta [Serialized.Text = true]) in type table [Team = _t, Sales = _t, Countries = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Team", type text}, {"Sales", Int64.Type}, {"Countries", type text}}),
    #"Split Column by Delimiter" = Table.SplitColumn(#"Changed Type", "Countries", Splitter.SplitTextByDelimiter(", ", QuoteStyle.Csv), {"Countries.1", "Countries.2"}),
    #"Changed Type1" = Table.TransformColumnTypes(#"Split Column by Delimiter",{{"Countries.1", type text}, {"Countries.2", type text}}),
    #"Unpivoted Columns" = Table.UnpivotOtherColumns(#"Changed Type1", {"Team", "Sales"}, "Attribute", "Value"),
    #"Added Conditional Column" = Table.AddColumn(#"Unpivoted Columns", "New Sale", each if [Attribute] = "Countries.1" then [Sales] else null),
    #"Removed Columns" = Table.RemoveColumns(#"Added Conditional Column",{"Sales", "Attribute"})
in
    #"Removed Columns"

Helpful resources

Announcements
Microsoft Fabric Learn Together

Microsoft Fabric Learn Together

Covering the world! 9:00-10:30 AM Sydney, 4:00-5:30 PM CET (Paris/Berlin), 7:00-8:30 PM Mexico City

PBI_APRIL_CAROUSEL1

Power BI Monthly Update - April 2024

Check out the April 2024 Power BI update to learn about new features.

April Fabric Community Update

Fabric Community Update - April 2024

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