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

Don't miss out! 2025 Microsoft Fabric Community Conference, March 31 - April 2, Las Vegas, Nevada. Use code MSCUST for a $150 discount. Prices go up February 11th. Register now.

Reply
jerryr125
Helper I
Helper I

Table value comparsion

Hi - I am looking to do the following in my Power Query workflow. I would like create a table of values not found comparing two tables.  Example:

 

Table 1

MS-IDAC-ID
1500
1600
2500
2555
2600
2750
3600

 

 

 

Table 2

MS-ID

AC-IDDate
150011/1/2024
150012/1/2024
250011/15/2024
25551/1/2025
26002/2/2025



Table 3 - Final Table

 

MS-IDAC-ID
1600
2750
3600


Therefore, table 3 consist of the rows in table 1 which are NOT in table 2.

 

Any thoughts ? 

 

Jerry

1 ACCEPTED SOLUTION

Yes:

= Table.NestedJoin(Table1, {"AC-ID", "MS-ID"}, Table2, {"AC-ID", "MS-ID"}, "DeleteThis", JoinKind.LeftAnti)

View solution in original post

6 REPLIES 6
jerryr125
Helper I
Helper I

Thank you everyone for your help - appreciate it!

 I acheive the end result using some creative joins!

AlienSx
Super User
Super User

Table.RemoveMatchingRows(Table1, Table.ToRecords(Table2), {"MS-ID", "AC-ID"})

I would never have thought of that combination of arguments with RemoveMatchingRows!

Omid_Motamedise
Super User
Super User

You can use List.Difference so, intially removed the column Date on the second table, then convert each one into a list by Table.ToRows, then use the List.Transform.

 

 

to see the preocess, just copy the next code into the advance editor

let
Table1= Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WMlTSUTI1MFCK1YGwzaBsIyRxMNvUFM5GVmNuCmEbw8RjAQ==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [#"MS-ID" = _t, #"AC-ID" = _t]),
    Table2 = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WMlTSUTI1MACShob6hvpGBkYmSrE6KOJGyOJGKOpN0SRMTUESEPWmcGEzsHojfSOocCwA", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [#"MS-ID" = _t, #"AC-ID" = _t, Date = _t]),
    Custom1 = List.Difference(Table.ToRows(Table1),Table.ToRows(Table.RemoveColumns(Table2,"Date"))),
    Custom2 = Table.FromRows(Custom1)

in
    Custom2

If this answer helped resolve your issue, please consider marking it as the accepted answer. And if you found my response helpful, I'd appreciate it if you could give me kudos. Thank you!

Anonymous
Not applicable

Why that sounds like a LeftAnti join. 

Yes:

= Table.NestedJoin(Table1, {"AC-ID", "MS-ID"}, Table2, {"AC-ID", "MS-ID"}, "DeleteThis", JoinKind.LeftAnti)

Helpful resources

Announcements
Las Vegas 2025

Join us at the Microsoft Fabric Community Conference

March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount!

Jan25PBI_Carousel

Power BI Monthly Update - January 2025

Check out the January 2025 Power BI update to learn about new features in Reporting, Modeling, and Data Connectivity.

December 2024

A Year in Review - December 2024

Find out what content was popular in the Fabric community during 2024.