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
fskhalasm
Frequent Visitor

split values into multiple rows

Hi,

 

can you help me with following task?

 

I have data like this:

1, A;B;C, X;Y;Z, 2, 3, 7

 

and I need to get:

1, A, X, 2, 3, 7

1, B, Y, 2, 3, 7

1, C, Z, 2, 3, 7

 

Any suggestion is appreciated.

Thank.

 

Marian

1 ACCEPTED SOLUTION

Add a custom column with this formula:

 

= Table.AddColumn(Source, "Custom", each Table.FromColumns({Text.Split([Column2], ";"), Text.Split([Column3], ";")}))

and then expand the resulting table.

 

Where Column2 and Column3 are the names of the columns who have multiple values in them and Source is the name of the previous step or the name of your query that you're referencing.

 

Edit 2018-10-31: You can also use this more generic function, that saves some typing when using multiple columns:

 

(Table as table, Delimiter as text, ListOfColumnNames) =>

Table.AddColumn(Table, 
"TableFromColumns",
each Table.FromColumns(List.Transform(ListOfColumnNames,
(x) => Text.Split(Record.Field(_, x),
Delimiter))))

Imke Feldmann (The BIccountant)

If you liked my solution, please give it a thumbs up. And if I did answer your question, please mark this post as a solution. Thanks!

How to integrate M-code into your solution -- How to get your questions answered quickly -- How to provide sample data -- Check out more PBI- learning resources here -- Performance Tipps for M-queries

View solution in original post

10 REPLIES 10
Baskar
Resident Rockstar
Resident Rockstar

I have data like this:

1, A;B;C, X;Y;Z, 2, 3, 7

 

 

It was in Sinlge cell ?

No, not in one cell,

It is comma separated - each comma one cell:

 

  • first cell contains 1
  • second cell contains A;B;C
  • third cell contains X;Y;Z
  • fourth cell contains 2
  • etc...

 

There are of course many rows, this is just one row example.

 

M.

Cool, 

 

We can do using Power Query, but am not sure it is better way.

 

My point is we can do everything . Folllow the images step by step .

Your Data etYour Data etSplit the two column by  ( ; )Split the two column by ( ; )Merge two column like the Example.Merge two column like the Example.After merge the three column by (  , )After merge the three column by ( , )Choose that three column and click Unpivot itChoose that three column and click Unpivot itRemove Attribute columnRemove Attribute columnSplit the value by ( , )Split the value by ( , )Final OutputFinal Output

 

 

Let me know if it is not helping u.

 

Note : 

  these all steps u have to do in Query Editor window

Thanks for you suggestion it can help me a bit.

The thing is that the semicomma separated values (A;B;C) are not always three in each row (can be two, three, four, etc - theoretically any count):

 

1, A;B;C, X;Y;Z, 2, 3, 7

5, A;B;C;D, V;X;Y;Z, 5, 3, 6

2, A;B, Y;Z, 4, 1, 6

Add a custom column with this formula:

 

= Table.AddColumn(Source, "Custom", each Table.FromColumns({Text.Split([Column2], ";"), Text.Split([Column3], ";")}))

and then expand the resulting table.

 

Where Column2 and Column3 are the names of the columns who have multiple values in them and Source is the name of the previous step or the name of your query that you're referencing.

 

Edit 2018-10-31: You can also use this more generic function, that saves some typing when using multiple columns:

 

(Table as table, Delimiter as text, ListOfColumnNames) =>

Table.AddColumn(Table, 
"TableFromColumns",
each Table.FromColumns(List.Transform(ListOfColumnNames,
(x) => Text.Split(Record.Field(_, x),
Delimiter))))

Imke Feldmann (The BIccountant)

If you liked my solution, please give it a thumbs up. And if I did answer your question, please mark this post as a solution. Thanks!

How to integrate M-code into your solution -- How to get your questions answered quickly -- How to provide sample data -- Check out more PBI- learning resources here -- Performance Tipps for M-queries

@ImkeF can you clarify how the generic solution below works.  I don't see a way to identify the delimiter type, #(lf) in my case, and for whatever reason when I paste this into PBI it is hitting a syntax error in the middle of the first "delimiter".   I have about 40 columns of data that this is the perfect solution for, would love any help you can provide.

 

Thanks!

@VEG_Admin ,

it shouldn't return errors. Please check this code:

 

let

    MyFunction = (Table as table, Delimiter as text, ListOfColumnNames) =>
                    Table.AddColumn(Table, 
                            "TableFromColumns", 
                            each Table.FromColumns(List.Transform(ListOfColumnNames, 
                                                (x) => Text.Split(Record.Field(_, x),                                                                                                    
                                                            Delimiter)))),
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("DcinAQAwDAOwX4xDOnnnE3Fe8P+wFZQ7EpWpAsOgJrUQ5qhUo/rfTR3qIuIB", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type text) meta [Serialized.Text = true]) in type table [Column1 = _t, Column2 = _t]),
    Custom1 = MyFunction(Source, "(#)#(lf)", {"Column1", "Column2"} )
in
    Custom1

 

Imke Feldmann (The BIccountant)

If you liked my solution, please give it a thumbs up. And if I did answer your question, please mark this post as a solution. Thanks!

How to integrate M-code into your solution -- How to get your questions answered quickly -- How to provide sample data -- Check out more PBI- learning resources here -- Performance Tipps for M-queries

Hello Imkef,

 

After a while, I need to implement your solution, but don't know where and how.

 

I m on "Import Data", and I have only one multiple values column to split. Can you please help ?

 

Regards

Please have a look at this video which shows how to integrate M-code into your solution:

https://community.powerbi.com/t5/Webinars-and-Video-Gallery/Power-BI-Forum-Help-How-to-integrate-M-c...

Imke Feldmann (The BIccountant)

If you liked my solution, please give it a thumbs up. And if I did answer your question, please mark this post as a solution. Thanks!

How to integrate M-code into your solution -- How to get your questions answered quickly -- How to provide sample data -- Check out more PBI- learning resources here -- Performance Tipps for M-queries

Thanks Imke, this works perfectly Smiley Happy

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.