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
Anonymous
Not applicable

Merge tables with multiple conditions in Power Query

Hi all, I'm trying to merge two tables a FACT Table and a DIM Table. It can easily be done in SQL with a LEFT JOIN, but was curious if there was a way to do this in Power Query. I am trying to pull values from the DIM table however the join is not on the Primary Key column but rather another column ,NumID, which contains duplicate values. Please let me know if more details are needed.

 

SQL Statement:

LEFT JOIN DIM ON DIM.NumID = FACT.CaseStatus AND DIM.Category = 'CaseStatus'

 

FACT Table

CaseIDCaseStatusCaseTypeCaseTierCaseOrigin
11111
22222
33333

 

DIM Table

KEYNumIDCategoryValue
11CaseStatusStatus1
22

CaseStatus

Status2
33

CaseStatus

Status3
41CaseTypeType1
52CaseTypeType2
63CaseType

Type3

 

Result:

FACT Table (After Merge)

CaseIDCaseStatusCaseTypeCaseTierCaseOrigin
1Status1Type1Tier1Origin1
2Status2Type2Tier2Origin2
3Status3Type3Tier3Origin3

 

 

 

1 ACCEPTED SOLUTION
jgeddes
Super User
Super User

I think what you are looking for would be written like this in Power Query...

= Table.NestedJoin(#"Changed Type", {"CaseStatus"}, Table.SelectRows(#"DIM Table", each [Category] = "CaseStatus"), {"NumID"}, "DIM Table", JoinKind.LeftOuter)

In this code there is a Left Outer join between the FACT Table 'CaseStatus' column (#"Changed Type" is the last step before the join in the FACT Table) and the DIM Table 'Num ID' column, The DIM Table is filtered to select rows that have Category = 'CaseStatus'.




Did I answer your question? Mark my post as a solution!

Proud to be a Super User!





View solution in original post

2 REPLIES 2
Anonymous
Not applicable

That's what I was looking for. Thank you very much.

jgeddes
Super User
Super User

I think what you are looking for would be written like this in Power Query...

= Table.NestedJoin(#"Changed Type", {"CaseStatus"}, Table.SelectRows(#"DIM Table", each [Category] = "CaseStatus"), {"NumID"}, "DIM Table", JoinKind.LeftOuter)

In this code there is a Left Outer join between the FACT Table 'CaseStatus' column (#"Changed Type" is the last step before the join in the FACT Table) and the DIM Table 'Num ID' column, The DIM Table is filtered to select rows that have Category = 'CaseStatus'.




Did I answer your question? Mark my post as a solution!

Proud to be a Super User!





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!

Dec Fabric Community Survey

We want your feedback!

Your insights matter. That’s why we created a quick survey to learn about your experience finding answers to technical questions.

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.

Top Solution Authors