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

Earn a 50% discount on the DP-600 certification exam by completing the Fabric 30 Days to Learn It challenge.

Reply
LetsLearnPower
New Member

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
LetsLearnPower
New Member

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
LearnSurvey

Fabric certifications survey

Certification feedback opportunity for the community.

PBI_APRIL_CAROUSEL1

Power BI Monthly Update - April 2024

Check out the April 2024 Power BI update to learn about new features.

April Fabric Community Update

Fabric Community Update - April 2024

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

Top Solution Authors
Top Kudoed Authors