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

Be one of the first to start using Fabric Databases. View on-demand sessions with database experts and the Microsoft product team to learn just how easy it is to get started. Watch now

Reply
rjrn
Frequent Visitor

What to do when Merge JoinKind.RightAnti returns NO rows?

Hi all!

 

I am trying to make a Merge JoinKind.RightAnti on 2 queries to get only the rows that are in the 2nd query. Most of the times it works, since there ARE rows in the 2nd query that ARE NOT in the 1st query.

 

The issue is when all rows from the 2nd query ARE in the 1st query. Then I get an error:

Expression.Error: There weren't enough elements in the enumeration to complete the operation

How do I handle this error so that I can still use the Merge query in other queries? How do I get a blank row instead of an error?

 

Any help is very much appreciated!

 

Regards,

RN

1 ACCEPTED SOLUTION
MarcelBeug
Community Champion
Community Champion

An empty Table2 means Table2 without records.
So you have the columns and their data types, so the rest of your code runs without errors.

 

My solution translated to your query (not tested, but it should be OK):

 

let
    Source = Table.NestedJoin(CW_opps,{"Opportunity Id18"},PW_opps,{"Opportunity Id18"},"PW_opps",JoinKind.RightAnti),
    PW_opps1 = try Source{0}[PW_opps] otherwise Table.SelectRows(PW_opps, each false),
    #"Removed Columns" = Table.RemoveColumns(PW_opps1,{"Proposal Due Date","Stage"})
in
    #"Removed Columns"
Specializing in Power Query Formula Language (M)

View solution in original post

4 REPLIES 4
MarcelBeug
Community Champion
Community Champion

It depends on your query code.

 

Suppose your "Merge1" query is only the merge and nothing else::

 

= Table.NestedJoin(Table1,{"ID"},Table2,{"ID"},"Table2",JoinKind.RightAnti)

 

 

And if your followup query refers to Merge1[Table2](0), then you can use try .. otherwise and have an empty Table2 returned in case of an error.:

 

= try Merge1[Table2]{0} otherwise Table.SelectRows(Table2, each false)
Specializing in Power Query Formula Language (M)

Thank you!

 

Here is the Merge1:

let
    Source = Table.NestedJoin(CW_opps,{"Opportunity Id18"},PW_opps,{"Opportunity Id18"},"PW_opps",JoinKind.RightAnti),
    PW_opps1 = Source{0}[PW_opps],
    #"Removed Columns" = Table.RemoveColumns(PW_opps1,{"Proposal Due Date","Stage"})
in
    #"Removed Columns"

Sorry for the stupid questions, but what do you mean with "have an empty Table2 returned in case of an error"?

 

Regards, RN

MarcelBeug
Community Champion
Community Champion

An empty Table2 means Table2 without records.
So you have the columns and their data types, so the rest of your code runs without errors.

 

My solution translated to your query (not tested, but it should be OK):

 

let
    Source = Table.NestedJoin(CW_opps,{"Opportunity Id18"},PW_opps,{"Opportunity Id18"},"PW_opps",JoinKind.RightAnti),
    PW_opps1 = try Source{0}[PW_opps] otherwise Table.SelectRows(PW_opps, each false),
    #"Removed Columns" = Table.RemoveColumns(PW_opps1,{"Proposal Due Date","Stage"})
in
    #"Removed Columns"
Specializing in Power Query Formula Language (M)

THANK YOU!

This worked like a charm!

 

My very best, RN

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!

ArunFabCon

Microsoft Fabric Community Conference 2025

Arun Ulag shares exciting details about the Microsoft Fabric Conference 2025, which will be held in Las Vegas, NV.

December 2024

A Year in Review - December 2024

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