Advance your Data & AI career with 50 days of live learning, dataviz contests, hands-on challenges, study groups & certifications and more!
Get registeredGet Fabric Certified for FREE during Fabric Data Days. Don't miss your chance! Request now
Hi,
I need some help to understand how I should work with two fact tables that does not have all the dimensions in each fact table.
I have uploaded an example pbix so you can easily try it out.
Link to pbix:
I want to calculate the total salery amount based on days worked and the daily salery.
The model should also allow me to filter by location, salery type and month.
The issue I meet is that I don't have the location in the days worked table. I only know how many days they have worked. So when create a table it will not filter out Lisa who has not worked at Building 1. What is the best way of solving this?
Is it possible to create a measure that allows me to calculate the totalt salery correctly or maybe create one fact table with the days worked, and still be able to filter by location and salery type?
the wanted output in the example shold be:
Namedaily salerydays workedSallery total
| Christian | 1700,95 | 23 | 39121,85 |
| Scot | 1882,45 | 27 | 50826,15 |
| Total | 3583,4 | 50 | 179170 |
Solved! Go to Solution.
In additions I implemented the solution for you. Below the calculated table (first disconnect Days and then calculate table!)
extraTable =
VAR __cartesian = ALL(Salery[EMP Number],Salery[Month], Salery[Location])
VAR __tableWithAllocatedDays =
ADDCOLUMNS(
__cartesian,
"@AllocatedDays",
DIVIDE(
SUMX(FILTER(Salery, Salery[EMP Number] = EARLIER(Salery[EMP Number]) && Salery[Month] = EARLIER(Salery[Month]) && Salery[Location] = EARLIER(Salery[Location])), Salery[Daily salery]),
SUMX(FILTER(Salery, Salery[EMP Number] = EARLIER(Salery[EMP Number]) && Salery[Month] = EARLIER(Salery[Month])), Salery[Daily salery])
) *
SUMX(FILTER('Days at work', 'Days at work'[Emp Number] = EARLIER(Salery[EMP Number]) && 'Days at work'[Month] = EARLIER(Salery[Month])),'Days at work'[Days])
)
RETURN
__tableWithAllocatedDaysGiving this visual:
Allocate the Days to a location on basis of the weighted average of Daily Salary per Location. So EMP number 1 will have the Days allocated for 99.9% to location 1 and for 0.1% to location 2.
Make a new table with these allocations, disconnect the old Days table and connect the new one to the dimension tables (including Locations).
Good luck!
In additions I implemented the solution for you. Below the calculated table (first disconnect Days and then calculate table!)
extraTable =
VAR __cartesian = ALL(Salery[EMP Number],Salery[Month], Salery[Location])
VAR __tableWithAllocatedDays =
ADDCOLUMNS(
__cartesian,
"@AllocatedDays",
DIVIDE(
SUMX(FILTER(Salery, Salery[EMP Number] = EARLIER(Salery[EMP Number]) && Salery[Month] = EARLIER(Salery[Month]) && Salery[Location] = EARLIER(Salery[Location])), Salery[Daily salery]),
SUMX(FILTER(Salery, Salery[EMP Number] = EARLIER(Salery[EMP Number]) && Salery[Month] = EARLIER(Salery[Month])), Salery[Daily salery])
) *
SUMX(FILTER('Days at work', 'Days at work'[Emp Number] = EARLIER(Salery[EMP Number]) && 'Days at work'[Month] = EARLIER(Salery[Month])),'Days at work'[Days])
)
RETURN
__tableWithAllocatedDaysGiving this visual:
Thanks you so much! You saved my week and I learned alot 🤩
Advance your Data & AI career with 50 days of live learning, contests, hands-on challenges, study groups & certifications and more!
Check out the October 2025 Power BI update to learn about new features.
| User | Count |
|---|---|
| 8 | |
| 6 | |
| 4 | |
| 4 | |
| 4 |
| User | Count |
|---|---|
| 25 | |
| 17 | |
| 8 | |
| 7 | |
| 6 |