Power BI is turning 10, and we’re marking the occasion with a special community challenge. Use your creativity to tell a story, uncover trends, or highlight something unexpected.
Get startedJoin us for an expert-led overview of the tools and concepts you'll need to become a Certified Power BI Data Analyst and pass exam PL-300. Register now.
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! | |
This is your chance to engage directly with the engineering team behind Fabric and Power BI. Share your experiences and shape the future.
Check out the June 2025 Power BI update to learn about new features.
User | Count |
---|---|
15 | |
11 | |
8 | |
8 | |
7 |
User | Count |
---|---|
15 | |
13 | |
9 | |
6 | |
6 |