Power BI is turning 10! Tune in for a special live episode on July 24 with behind-the-scenes stories, product evolution highlights, and a sneak peek at what’s in store for the future.
Save the dateEnhance your career with this limited time 50% discount on Fabric and Power BI exams. Ends August 31st. Request your voucher.
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
CaseID | CaseStatus | CaseType | CaseTier | CaseOrigin |
1 | 1 | 1 | 1 | 1 |
2 | 2 | 2 | 2 | 2 |
3 | 3 | 3 | 3 | 3 |
DIM Table
KEY | NumID | Category | Value |
1 | 1 | CaseStatus | Status1 |
2 | 2 | CaseStatus | Status2 |
3 | 3 | CaseStatus | Status3 |
4 | 1 | CaseType | Type1 |
5 | 2 | CaseType | Type2 |
6 | 3 | CaseType | Type3 |
Result:
FACT Table (After Merge)
CaseID | CaseStatus | CaseType | CaseTier | CaseOrigin |
1 | Status1 | Type1 | Tier1 | Origin1 |
2 | Status2 | Type2 | Tier2 | Origin2 |
3 | Status3 | Type3 | Tier3 | Origin3 |
Solved! Go to Solution.
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'.
Proud to be a Super User! | |
That's what I was looking for. Thank you very much.
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'.
Proud to be a Super User! | |
Check out the July 2025 Power BI update to learn about new features.