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
jdormer
Helper I
Helper I

Concatenate Alphabetically

Hi, 

 

I am building a report on data pulled from a SharePoint task list. One of the fields is "Assigned To" which can have multiple values. This field is available in Power BI as a "record," which I expanded to get the field values as text. If two tasks have the same users in the "Assigned To" field, but not listed in the same order, those values are not recognized as being the same. For example, I could have the following two values to "Assigned To":

 

"Jane Doe; John Doe"

"John Doe; Jane Doe"

 

I would like these to be considered the same in my report. To that end, I've duplicated my table, keeping only the "Assigned To" field that I want to work with. I then split the field on the semicolon delimiter. Now, I'd like to concatenate the resultant values, sorted alphabetically, so that the values are the same regardless of the order they are entered. Is this possible?

 

If there is an alternative approach that would achieve the outcome I am looking for, I'd welcome other ideas. 

 

Thanks.

1 ACCEPTED SOLUTION
v-yuezhe-msft
Employee
Employee

@jdormer,

Firstly, after your split your column, replace the space in your data with semicolon.
1.PNG

Secondly, merge the two columns using “Merge Columns” feature.
2.PNG

Thirdly, create a custom column using the following formula.

=Text.Combine(List.Sort(Text.Split(Text.From([Merged]), ";"),Order.Ascending),";")
3.PNG

For more details, please review this PBIX file.


Regards,

 

Community Support Team _ Lydia Zhang
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

2 REPLIES 2
v-yuezhe-msft
Employee
Employee

@jdormer,

Firstly, after your split your column, replace the space in your data with semicolon.
1.PNG

Secondly, merge the two columns using “Merge Columns” feature.
2.PNG

Thirdly, create a custom column using the following formula.

=Text.Combine(List.Sort(Text.Split(Text.From([Merged]), ";"),Order.Ascending),";")
3.PNG

For more details, please review this PBIX file.


Regards,

 

Community Support Team _ Lydia Zhang
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

@v-yuezhe-msft thank you! To clarify, The result I am looking for is that both columns show as "Jane Doe; John Doe;" so the steps provided actually go a bit further than necessary for my use case. I was able to use the third formula you provided to achieve the result I desired. Thanks again!

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.