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

The Power BI DataViz World Championships are on! With four chances to enter, you could win a spot in the LIVE Grand Finale in Las Vegas. Show off your skills.

Reply
madluolis
New Member

Column with comma separated values to list

Seeking for kind help in respect a problem which I have, I have next table, which contains two columns, one with comma separated values:

 

Name| Country
Maria| Spain, Portugal, Italy
Pedro| Spain, Italy
Jose| France, Germany, Italy
Carlos| Germany, Spain
Ana| Spain, Portugal, Italy, France, Germany

 

I need to find a way how to convert this so that each comma separed value in column Country comes to a own row and Name will repeat for each matching case, so like below:

Name| Country
Maria| Spain
Maria| Portugal
Maria| Italy
Jose| France
Jose| Germany
Jose| Italy
Carlos| Germany
Carlos| Spain
Ana| Spain
Ana| Portugal
Ana| Italy
Ana| France
Ana| Germany

 

Thank you for your help!

 

 

1 ACCEPTED SOLUTION
pfarias
Advocate I
Advocate I

You can add a new column using the Text.Split function as in the example:

 

=Text.Split([Country], ",")

 

pfarias_0-1657222062314.png

 

A new column of type List will be created. Then just expand it.

pfarias_1-1657222227547.png

 

View solution in original post

2 REPLIES 2
pfarias
Advocate I
Advocate I

You can add a new column using the Text.Split function as in the example:

 

=Text.Split([Country], ",")

 

pfarias_0-1657222062314.png

 

A new column of type List will be created. Then just expand it.

pfarias_1-1657222227547.png

 

Vijay_A_Verma
Super User
Super User

See the working here - Open a blank query - Home - Advanced Editor - Remove everything from there and paste the below code to test

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45W8k0sykxU0lEKLkjMzNNRCMgvKilNT8zRUfAsScypVIrViVYKSE0pykcoQUh45RenAsXdihLzklN1FNxTi3IT8yqRVTgnFuXkFwPVwOXAhoDlHPNw26ujgGaoUmwsAA==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Name = _t, Country = _t]),
    Custom1 = Table.ReplaceValue(Source,each [Country],each Text.Split([Country],", "),Replacer.ReplaceValue,{"Country"}),
    #"Expanded Country" = Table.ExpandListColumn(Custom1, "Country")
in
    #"Expanded Country"

 

Helpful resources

Announcements
Las Vegas 2025

Join us at the Microsoft Fabric Community Conference

March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount!

Feb2025 Sticker Challenge

Join our Community Sticker Challenge 2025

If you love stickers, then you will definitely want to check out our Community Sticker Challenge!

Feb2025 NL Carousel

Fabric Community Update - February 2025

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

Top Solution Authors
Top Kudoed Authors