cancel
Showing results for 
Search instead for 
Did you mean: 
Reply
Anonymous
Not applicable

HELP: Matching a value in one column to a value from another column (but different row)

Hi,

 

I'm relatively new to using Power Query, and I just can't figure out how to do what I can do with DAX in Power Query.

I'm trying to get a new column that returns True if the value in a row of one column matches with any of the rows in another column, and a False if it does not match. 

 

In DAX I used this function: CONTAINS(Table1,Table1[column1],Table1[column2]) and this worked fine. However, I want to be able to use that column for further transformations or conditions in the Query Editor, so I need to replicate this using Power Query, but I can't find any examples that do this. 

 

It should look something like this:

So if the values from either the Other_PersonID1 or the values from the Other_PersonID2 match any case in the column Person_ID, then you return "True", if there is no match, then it returns "False".

Person_IDOther_PersonID1Other_PersonID2Match
1 2True
27 True
3 20False
48 True
5 4True
69 True
7 9True
8  False
9  False

 

 

1 ACCEPTED SOLUTION
v-juanli-msft
Community Support
Community Support

Hi @Anonymous 

Add custom columns

Capture8.JPG

List.Contains(#"Removed Columns"[Person_ID],[Other_PersonID1]) or List.Contains(#"Removed Columns"[Person_ID],[Other_PersonID2])

Replace #"Removed Columns" with the previous step in your case.

 

Best Regards
Maggie
Community Support Team _ Maggie Li
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

4 REPLIES 4
v-juanli-msft
Community Support
Community Support

Hi @Anonymous 

Add custom columns

Capture8.JPG

List.Contains(#"Removed Columns"[Person_ID],[Other_PersonID1]) or List.Contains(#"Removed Columns"[Person_ID],[Other_PersonID2])

Replace #"Removed Columns" with the previous step in your case.

 

Best Regards
Maggie
Community Support Team _ Maggie Li
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

Anonymous
Not applicable

Thank you very much, this works perfectly!

mcybulski
Solution Specialist
Solution Specialist

This code will handle looking up mutliple columns in one merge.

 

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("NYnJDQAgCAR72TcPb6UWYv9tyCEJITM7Iqgg6DVcEv2EbYNJ/6W4DcWTaUYaLkuJs+wo7HJCnDn5Pg==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type text) meta [Serialized.Text = true]) in type table [Person_ID = _t, Other_PersonID1 = _t, Other_PersonID2 = _t]),
    #"Unpivoted Other Columns" = Table.UnpivotOtherColumns(Source, {"Person_ID"}, "Attribute", "Value"),
    #"Merged Queries" = Table.NestedJoin(#"Unpivoted Other Columns", {"Value"}, #"Unpivoted Other Columns", {"Person_ID"}, "Unpivoted Other Columns", JoinKind.LeftOuter),
    Transform = Table.TransformColumns(#"Merged Queries",{{"Unpivoted Other Columns", each not List.IsEmpty([Value])}}),
    #"Grouped Rows" = Table.Group(Transform, {"Person_ID"}, {{"Match", each 
List.AnyTrue([#"Unpivoted Other Columns"])}})
in
    #"Grouped Rows"

 

v-juanli-msft
Community Support
Community Support

Hi @Anonymous 

This may be helpful.

https://stackoverflow.com/questions/51927925/powerquery-in-operator-in-conditional-column

 

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

Helpful resources

Announcements
UG GA Amplification 768x460.png

Launching new user group features

Learn how to create your own user groups today!

November Power BI Update 768x460.png

Check it Out!

Click here to read more about the November 2021 Updates!

M365 768x460.jpg

Microsoft 365 Collaboration Conference | December 7–9, 2021

Join us, in-person, December 7–9 in Las Vegas, for the largest gathering of the Microsoft community in the world.

Top Kudoed Authors