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

Compete to become Power BI Data Viz World Champion! First round ends August 18th. Get started.

Reply
DataArch17
New Member

Combine multiple columns to one one column with delimiter

I have a dataset as below. I want to combine 4 columns (Col 1, Col 2, Col 3, Col 4) to one column with delimiter and only with UNINQUE values. Is this possible in M query / DAX?

 

If I do a normal merge in M I am unable to ignore duplicate values as in first row. We have two 123s. And I am unable to ignore delimiter if no values as in 2nd row I am getting :::123 since Col 1, 2, 4 is NULLL

 

NameLocationDateCode 1Code 2Code 3Code 4Result Column
JohnIndia01-Jan-24123 456123123; 456
JaceUK02-Jan-24  123 123
2 ACCEPTED SOLUTIONS
johnbasha33
Super User
Super User

@DataArch17 

To achieve this in Power Query (M Query), you can use the following steps:

1. Load your dataset into Power Query.
2. Add a custom column that concatenates the values of Col 1, Col 2, Col 3, and Col 4 into a list.
3. Remove duplicate values from the list.
4. Convert the list back to text with your desired delimiter.
5. Handle the case where all values are NULL.

Here's the M Query code to achieve this:

```m
let
Source = YourDataSourceHere, // Replace this with your actual data source
AddCustomColumn = Table.AddColumn(Source, "Combined", each List.RemoveNulls({[Col 1], [Col 2], [Col 3], [Col 4]})),
RemoveDuplicates = Table.TransformColumns(AddCustomColumn, {"Combined", each List.Distinct(_)}),
ConvertToList = Table.TransformColumns(RemoveDuplicates, {"Combined", each Text.Combine(List.Transform(_, Text.From)), type text}),
HandleEmptyValues = Table.TransformColumns(ConvertToList, {"Combined", each if _ = "" then null else _})
in
HandleEmptyValues
```

This code adds a new column "Combined" to your table where the values of Col 1, Col 2, Col 3, and Col 4 are combined into a single text value with unique values separated by your desired delimiter. It also handles the case where all values are NULL by converting the result to null.

After applying these transformations, your dataset should have a new column with the desired concatenated and unique values.

Did I answer your question? Mark my post as a solution! Appreciate your Kudos !!

View solution in original post

Anonymous
Not applicable

Hi, @DataArch17 

Thanks to HotChilli's thoughts, here's my detailed addition to this.

Start by changing your data type to Text type, then create a custom column and use the following M expression:

 

= Table.AddColumn(#"Changed Type", "Combined", each Text.Combine(List.Distinct({[Code 1], [Code 2], [Code 3], [Code 4]}), ";"))

 

 

vyohuamsft_0-1714115265127.png

 

How to Get Your Question Answered Quickly 

Best Regards

Yongkang Hua

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

5 REPLIES 5
Anonymous
Not applicable

Hi, @DataArch17 

Thanks to HotChilli's thoughts, here's my detailed addition to this.

Start by changing your data type to Text type, then create a custom column and use the following M expression:

 

= Table.AddColumn(#"Changed Type", "Combined", each Text.Combine(List.Distinct({[Code 1], [Code 2], [Code 3], [Code 4]}), ";"))

 

 

vyohuamsft_0-1714115265127.png

 

How to Get Your Question Answered Quickly 

Best Regards

Yongkang Hua

If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

@Anonymous Thank you so much. Worked like a charm.

johnbasha33
Super User
Super User

@DataArch17 

To achieve this in Power Query (M Query), you can use the following steps:

1. Load your dataset into Power Query.
2. Add a custom column that concatenates the values of Col 1, Col 2, Col 3, and Col 4 into a list.
3. Remove duplicate values from the list.
4. Convert the list back to text with your desired delimiter.
5. Handle the case where all values are NULL.

Here's the M Query code to achieve this:

```m
let
Source = YourDataSourceHere, // Replace this with your actual data source
AddCustomColumn = Table.AddColumn(Source, "Combined", each List.RemoveNulls({[Col 1], [Col 2], [Col 3], [Col 4]})),
RemoveDuplicates = Table.TransformColumns(AddCustomColumn, {"Combined", each List.Distinct(_)}),
ConvertToList = Table.TransformColumns(RemoveDuplicates, {"Combined", each Text.Combine(List.Transform(_, Text.From)), type text}),
HandleEmptyValues = Table.TransformColumns(ConvertToList, {"Combined", each if _ = "" then null else _})
in
HandleEmptyValues
```

This code adds a new column "Combined" to your table where the values of Col 1, Col 2, Col 3, and Col 4 are combined into a single text value with unique values separated by your desired delimiter. It also handles the case where all values are NULL by converting the result to null.

After applying these transformations, your dataset should have a new column with the desired concatenated and unique values.

Did I answer your question? Mark my post as a solution! Appreciate your Kudos !!

Thank you @johnbasha33 

HotChilli
Super User
Super User

Create a list with list.distinct.

Filter the list for any values you don't want using List.Select.

Then use Text.Combine to get the final column.

https://learn.microsoft.com/en-us/powerquery-m/text-combine 

Helpful resources

Announcements
August Power BI Update Carousel

Power BI Monthly Update - August 2025

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

August 2025 community update carousel

Fabric Community Update - August 2025

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

Top Solution Authors