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

Get Fabric Certified for FREE during Fabric Data Days. Don't miss your chance! Request now

Reply
OKgo
Helper IV
Helper IV

A more robust Table.SplitColumn / Splitter.SplitTextByDelimiter

I have a dataset with ISO countries stored in one column e.g. "USA, CAN, MEX, GBR, DEU, POL". This will grow as the database grows. Is there a way to future proof this PQ to account for that growth? I made some tests with more than 6 counties and the hardcoding then ommits critical data.

 

= Table.SplitColumn(#"Removed Other Columns", "* Merge Colum 9 & 11", Splitter.SplitTextByDelimiter(",", QuoteStyle.Csv), {"Column9.1", "Column9.2", "Column9.3", "Column9.4", "Column9.5", "Column9.6"})

 

Thank you

 

2 ACCEPTED SOLUTIONS
Anonymous
Not applicable

a probably more efficient way would be this:

 

 

 

 

 

 

    nrows=Table.RowCount(yourTab),
    split=Table.FromColumns(List.Zip(List.Transform({0..nrows-1},each Text.Split(yourTab[country]{_},","))))
in
    split

 

 

 

PS

If Table.TransformRows had, as Table.TransformColumns has, the ability to manage lists of different lengths, there would have been no need to use the List.zip function to do an intermediate step.

 

View solution in original post

Anonymous
Not applicable

aahhh ... 😀  ok, now  I see.

 

you have a table like this (ONLY ONE COUNTRY LIST PER PartNumber. Is it true?)):

 

image.png

 

 

and want a table like this (only first rows are displayed):

 

image.png

 

 

all you need is in this line (no adda column, no unpivot, no delete lines,...) :

 

Table.ExpandListColumn(Table.Group(yourTab, {"PartNumber"}, {{"split", each Text.Split(_[country]{0},",")}}),"split")

 

PS

or more directly e I tink clearer

 

Table.ExpandListColumn(Table.TransformColumns(yourTab, {"country", each Text.Split(_,",")}),"country")

View solution in original post

9 REPLIES 9
Anonymous
Not applicable

if you are sure the length/composition of string is constant between different rows, you can manage the future different input in in this way:

 

 

cols=Text.Split(yourTab[country]{0},","),
colSpl = Table.SplitColumn(yourTab, "country", Splitter.SplitTextByDelimiter(",", QuoteStyle.None), cols)


in
colSpl

 

 

If the length/strcture of string could varies between the different lines, you need some more line of code to manage the situation.

 

Thank you @Anonymous . Unfortuneatly the number of coutnries varies from null to a probable max of 50. The end goal is to turn
"PartNumber1", "USA, MEX, CAN"

into something like this duplicating the data

"PartNumber1", "USA"

"PartNumber1", "MEX"
"PartNumber1", "CAN"

 

Maybe I am using my Excel user interface brain too much and there is an easier PQ function I could be using.

 

Hardcoding 50 columns and unpivitoing is what could do - but I was hoping for some code I would not have to worry about periodly checking "oh I wonder do I have more than 50 countires today"

mahoneypat
Microsoft Employee
Microsoft Employee

Here is one way to do it in the query editor.  I am assuming you want a list of lists for use in a subsequent step, so you can delete the steps after the ListOfLists step, if so.

 

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WCkgsKvErzU1KLTJU0lEKDXbUcXb00/F1jVCKjQUA", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Column1 = _t, Column2 = _t]),
    #"Added Custom" = Table.AddColumn(Source, "Custom", each let col1 = [Column1] in List.Transform(Text.Split([Column2], ","), each {col1, _})),
    ListOfLists = #"Added Custom"{0}[Custom],
    #"Converted to Table" = Table.FromList(ListOfLists, Splitter.SplitByNothing(), null, null, ExtraValues.Error),
    #"Extracted Values" = Table.TransformColumns(#"Converted to Table", {"Column1", each Text.Combine(List.Transform(_, Text.From), ";"), type text}),
    #"Split Column by Delimiter" = Table.SplitColumn(#"Extracted Values", "Column1", Splitter.SplitTextByDelimiter(";", QuoteStyle.Csv), {"Column1.1", "Column1.2"}),
    TableVersion = Table.TransformColumnTypes(#"Split Column by Delimiter",{{"Column1.1", type text}, {"Column1.2", type text}})
in
    TableVersion

 

If this works for you, please mark it as the solution.  Kudos are appreciated too.  Please let me know if not.

Regards,

Pat





Did I answer your question? Mark my post as a solution! Kudos are also appreciated!

To learn more about Power BI, follow me on Twitter or subscribe on YouTube.


@mahoneypa HoosierBI on YouTube


Thank you @mahoneypat 

 

I am really sorry I not great in advanced editor. And I am failing to transplant (and understand) your kind input. I would like to see the first part before taking a look at the list of lists. I removed the BinaryEncoding.Base64 to get to the end of the santax errors and was hit with a null pointer exception I don't quite understand. 

 

let
Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("C:\Test.csv"),Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Column1 = _t, Column2 = _t]),
#"Added Custom" = Table.AddColumn(Source, "Custom", each let col1 = [Column1] in List.Transform(Text.Split([Column2], ","), each {col1, _}))
in

 

Test CSV file looks like this in notepad

"Column1"
"USA, AUT, DEU, LTU, NLD, ESP, GBR, CAN, LVA"
"AUT, DEU, LTU, NLD, ESP, GBR, CAN, LVA"
"USA, AUT, DEU, LTU, NLD, ESP, GBR, LVA"
"AUT, DEU, LTU, NLD, ESP, GBR, CAN, LVA"
"USA, AUT, DEU, LTU, NLD, ESP, GBR, CAN, LVA"
"USA, AUT, DEU, LTU, NLD, ESP, GBR, LVA"
"AUT, DEU, LTU, NLD, ESP, GBR, CAN, LVA"
"AUT, DEU, LTU, NLD, ESP, GBR, CAN, LVA
"AUT, DEU, LTU, NLD, ESP, GBR, CAN, LVA
"USA, ESP, CAN"
"USA, ESP, CAN"

 

Many thanks

Anonymous
Not applicable

Hi @OKgo , is not yet completely clear the startong and the ending point, but let me show you what I suppose and what I think can be done.

 

You have a column like this (which I called "country")

image.png

 

 

and you want to get a group of columns like these:

 

image.png

 

This can be done, by this code (with little adaptation, eventually):

 

    yourTab= Table.TransformColumnTypes(Tabella1_Table,{{"country", type text}}),
    nrows=Table.RowCount(yourTab),
    colsMax=List.Max(List.Transform({0..nrows-1},each List.Count(Text.PositionOf(yourTab[country]{_},",",Occurrence.All))))+1,
    countries=List.Transform({1..colsMax},each "col_"&Text.From(_)),
    colSpl = Table.SplitColumn(yourTab, "country", Splitter.SplitTextByDelimiter(",", QuoteStyle.None), countries)

in
    colSpl

The code can manage a variable number of max countries, and create as many columns as needed.

 

if you still want something different, give examples of the most general case that you want to be treated by giving the  input and desired output.

 

Anonymous
Not applicable

a probably more efficient way would be this:

 

 

 

 

 

 

    nrows=Table.RowCount(yourTab),
    split=Table.FromColumns(List.Zip(List.Transform({0..nrows-1},each Text.Split(yourTab[country]{_},","))))
in
    split

 

 

 

PS

If Table.TransformRows had, as Table.TransformColumns has, the ability to manage lists of different lengths, there would have been no need to use the List.zip function to do an intermediate step.

 

@mahoneypat Thank you so much for your support. I learnt a lot but a lot of it was above to transplant. 

 

@Anonymous  The "Text.Split" clue was very clear - I then searched this and found my exact situation!!

https://www.youtube.com/watch?v=9krfJLv8ENk

 

Thank you all

Anonymous
Not applicable

aahhh ... 😀  ok, now  I see.

 

you have a table like this (ONLY ONE COUNTRY LIST PER PartNumber. Is it true?)):

 

image.png

 

 

and want a table like this (only first rows are displayed):

 

image.png

 

 

all you need is in this line (no adda column, no unpivot, no delete lines,...) :

 

Table.ExpandListColumn(Table.Group(yourTab, {"PartNumber"}, {{"split", each Text.Split(_[country]{0},",")}}),"split")

 

PS

or more directly e I tink clearer

 

Table.ExpandListColumn(Table.TransformColumns(yourTab, {"country", each Text.Split(_,",")}),"country")

mahoneypat
Microsoft Employee
Microsoft Employee

If you paste the M code I provided into a blank query in the Advanced Editor (replace the text there).  Once you do that you can click through each step on the right to see what the data look like at each step (you don't need to delete anything).  The Source step is just the example data.

 

The key to the whole query is the step with "each let col1 = [Column1] ..."

 

How are you going to use the output of this query?  Do you need a list of lists? just a list, a table of values?  I'm assuming you need a list of lists to change column names, but please clarify.

 

Regards,

Pat





Did I answer your question? Mark my post as a solution! Kudos are also appreciated!

To learn more about Power BI, follow me on Twitter or subscribe on YouTube.


@mahoneypa HoosierBI on YouTube


Helpful resources

Announcements
Fabric Data Days Carousel

Fabric Data Days

Advance your Data & AI career with 50 days of live learning, contests, hands-on challenges, study groups & certifications and more!

October Power BI Update Carousel

Power BI Monthly Update - October 2025

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

FabCon Atlanta 2026 carousel

FabCon Atlanta 2026

Join us at FabCon Atlanta, March 16-20, for the ultimate Fabric, Power BI, AI and SQL community-led event. Save $200 with code FABCOMM.