cancel
Showing results for 
Search instead for 
Did you mean: 
Reply
mstoppelman
Frequent Visitor

Match between two columns in different order

Hi, I've got two calculated columns, so a Power Query solution isn't feasible, and I don't really know where to start, or if it's possible to achieve my expected result. The two columns have data separated by commas, and I want to check if what's between the commas matches, even if the items are in a different order.

 

Here is a visual of what I'm looking for, let's say this table is called "test"

Calculated Column1Calculated Column2Expected Result
ABC,DEFGH,IJIJ,ABC,DEFGH

Match

XYZ,MNOPQRLMN,TUVWXYZNo Match
2 ACCEPTED SOLUTIONS
AlexisOlson
Super User
Super User

This is annoying to do in DAX since there isn't a nice function to split the text. However, it's possible to abuse the PATH functions to accomplish this.

 

Expected Result = 
VAR Path1 = SUBSTITUTE ( Concat[Calculated Column1], ",", "|" )
VAR Path2 = SUBSTITUTE ( Concat[Calculated Column2], ",", "|" )
VAR Len1 = PATHLENGTH ( Path1 )
VAR Len2 = PATHLENGTH ( Path2 )
VAR List1 = SELECTCOLUMNS ( GENERATESERIES ( 1, Len1 ), "Item", PATHITEM ( Path1, [Value] ) )
VAR List2 = SELECTCOLUMNS ( GENERATESERIES ( 1, Len2 ), "Item", PATHITEM ( Path2, [Value] ) )
RETURN
    IF ( MAX ( Len1, Len2 ) = COUNTROWS ( INTERSECT ( List1, List2  ) ), "Match", "No Match" )

 

This turns each concatenation into a path and then constructs a list of each item in the path. Then if the intersection of these lists has as many items as each individual one, it's a match.

View solution in original post

mahoneypat
Microsoft
Microsoft

This would be much easier in Power Query.  Is it possible to make your Calculated Columns there instead, so you can do this too there?  Or is it indepent and you could do it there first?

 

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


View solution in original post

3 REPLIES 3
mahoneypat
Microsoft
Microsoft

This would be much easier in Power Query.  Is it possible to make your Calculated Columns there instead, so you can do this too there?  Or is it indepent and you could do it there first?

 

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


AlexisOlson
Super User
Super User

This is annoying to do in DAX since there isn't a nice function to split the text. However, it's possible to abuse the PATH functions to accomplish this.

 

Expected Result = 
VAR Path1 = SUBSTITUTE ( Concat[Calculated Column1], ",", "|" )
VAR Path2 = SUBSTITUTE ( Concat[Calculated Column2], ",", "|" )
VAR Len1 = PATHLENGTH ( Path1 )
VAR Len2 = PATHLENGTH ( Path2 )
VAR List1 = SELECTCOLUMNS ( GENERATESERIES ( 1, Len1 ), "Item", PATHITEM ( Path1, [Value] ) )
VAR List2 = SELECTCOLUMNS ( GENERATESERIES ( 1, Len2 ), "Item", PATHITEM ( Path2, [Value] ) )
RETURN
    IF ( MAX ( Len1, Len2 ) = COUNTROWS ( INTERSECT ( List1, List2  ) ), "Match", "No Match" )

 

This turns each concatenation into a path and then constructs a list of each item in the path. Then if the intersection of these lists has as many items as each individual one, it's a match.

Thank you so much! This works great

Helpful resources

Announcements
June 2022 update 768X460.jpg

Check it out!

Click here to read more about the June 2022 updates!

Power Platform Conf 2022 768x460.jpg

Join us for Microsoft Power Platform Conference

The first Microsoft-sponsored Power Platform Conference is coming in September. 100+ speakers, 150+ sessions, and what's new and next for Power Platform.

Power BI Dev Camp Session 23 768x460.jpg

Check it Out!

Mark your calendars and join us on Thursday, June 30 at 11a PDT for a great session with Ted Pattison!

June 20 episode 7 with aka link 768x460.jpg

The Power BI Community Show

Join us on June 20 at 11 am PDT when Kim Manis shares the latest on Azure Synapse analytics, the Microsoft Intelligent Data Platform, and notable Power BI Updates from Microsoft Build 2022.

Top Solution Authors