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

Earn the coveted Fabric Analytics Engineer certification. 100% off your exam for a limited time only!

Reply
Remco
Frequent Visitor

Left join that on match the first record of the right tabl

Hi, 

I'm looking for a way to join 2 table in Power Query. This should be a left join that only returns the first record of the right table. See my example below:

Left_join.png

1 ACCEPTED SOLUTION

Yes, you can use the "Aggregate"-tab instead of the "Expand"-tab, choose any of the defualt actions and replace the function by "List.First".

 

Table.AggregateTableColumn(#"Grouped Rows", "Count", {{"Case", List.Count, "Count of Case"}})

will become

Table.AggregateTableColumn(#"Grouped Rows", "Count", {{"Case", List.First, "Count of Case"}})

 

But performance might be a pain: https://www.thebiccountant.com/2019/10/28/performance-tip-for-aggregations-after-joins-in-power-quer...

 

Better just to reference the lookup table then, do the distinct manually and uncheck "load to data model" if you're going to use that table just for this purpose.

 

Imke Feldmann (The BIccountant)

If you liked my solution, please give it a thumbs up. And if I did answer your question, please mark this post as a solution. Thanks!

How to integrate M-code into your solution -- How to get your questions answered quickly -- How to provide sample data -- Check out more PBI- learning resources here -- Performance Tipps for M-queries

View solution in original post

6 REPLIES 6
BrandyBurk
Frequent Visitor

Use the fuzzy match when merging queries and set number of matches to 1.  Match threshold to 1.0

ImkeF
Super User
Super User

Use Table.Distinct(#"Right table", {"TrackingID"}) in the merge (by tweaking the code) or remove duplicates with the UI before the merge.

 

Imke Feldmann (The BIccountant)

If you liked my solution, please give it a thumbs up. And if I did answer your question, please mark this post as a solution. Thanks!

How to integrate M-code into your solution -- How to get your questions answered quickly -- How to provide sample data -- Check out more PBI- learning resources here -- Performance Tipps for M-queries

Remco
Frequent Visitor

That may work in my query, but I'm not sure how to apply this on the query below.

 

#"Merged Queries" = Table.NestedJoin(#"Renamed Columns", {"Shipment Number"}, BKM_UPS_D2L_carton_details_lookup, {"TrackingID"}, "BKM_UPS_D2L_carton_details_lookup", JoinKind.LeftOuter),
#"Expanded BKM_UPS_D2L_carton_details_lookup" = Table.ExpandTableColumn(#"Merged Queries", "BKM_UPS_D2L_carton_details_lookup", {"Virtual_Warehouse"}, {"BKM_UPS_D2L_carton_details_lookup.Virtual_Warehouse"}),
#"Renamed Columns2" = Table.RenameColumns(#"Expanded BKM_UPS_D2L_carton_details_lookup",{{"BKM_UPS_D2L_carton_details_lookup.Virtual_Warehouse", "Location TrackingID"}}),

Hi @Remco 

adjust the first step like so:

 

#"Merged Queries" = Table.NestedJoin(#"Renamed Columns", {"Shipment Number"}, Table.Distinct(BKM_UPS_D2L_carton_details_lookup, {"TrackingID"), {"TrackingID"}, "BKM_UPS_D2L_carton_details_lookup", JoinKind.LeftOuter),

 

Imke Feldmann (The BIccountant)

If you liked my solution, please give it a thumbs up. And if I did answer your question, please mark this post as a solution. Thanks!

How to integrate M-code into your solution -- How to get your questions answered quickly -- How to provide sample data -- Check out more PBI- learning resources here -- Performance Tipps for M-queries

Remco
Frequent Visitor

Query editor error says that it is missing a comma, but all comma's are at the right place in your query. But I also found out that my data is to 'dirty' voor Distinct. I have to dive deeper in the data of the second table.

Or is there an other solution to fetch only the first matching record of the right table?

Yes, you can use the "Aggregate"-tab instead of the "Expand"-tab, choose any of the defualt actions and replace the function by "List.First".

 

Table.AggregateTableColumn(#"Grouped Rows", "Count", {{"Case", List.Count, "Count of Case"}})

will become

Table.AggregateTableColumn(#"Grouped Rows", "Count", {{"Case", List.First, "Count of Case"}})

 

But performance might be a pain: https://www.thebiccountant.com/2019/10/28/performance-tip-for-aggregations-after-joins-in-power-quer...

 

Better just to reference the lookup table then, do the distinct manually and uncheck "load to data model" if you're going to use that table just for this purpose.

 

Imke Feldmann (The BIccountant)

If you liked my solution, please give it a thumbs up. And if I did answer your question, please mark this post as a solution. Thanks!

How to integrate M-code into your solution -- How to get your questions answered quickly -- How to provide sample data -- Check out more PBI- learning resources here -- Performance Tipps for M-queries

Helpful resources

Announcements
April AMA free

Microsoft Fabric AMA Livestream

Join us Tuesday, April 09, 9:00 – 10:00 AM PST for a live, expert-led Q&A session on all things Microsoft Fabric!

March Fabric Community Update

Fabric Community Update - March 2024

Find out what's new and trending in the Fabric Community.

Top Solution Authors
Top Kudoed Authors