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 all,
I understand that this is probably a specific issue to myself, however if you have time to assist that would be greatly appreciated!
Currently I have a 4 tables in my Power Bi:
From this, I want to replicate a formula from Excel that looks something like this -
"Current Weeks CarsOnHand" - "Previous Weeks CarsOnHand" + "Previous Weeks CarsCounted" (screenshot attached)
What would be my best way to approach this in Power Bi? I feel like I have all the right information for it to be achieved, just having some troubles with executing it.
Any help is appreciated.
Solved! Go to Solution.
Hi @clock0928 ,
I will start by showing you my test data:
To make it easier to see, I created a week table and used that to create a slicer:
I then used DAX to create the following three measures:
Total_CarsOnHand =
CALCULATE(
SUM('Work On Hand'[CarsOnHand]),
FILTER(
ALLSELECTED('Calendar'[WeekOfYear]),
'Calendar'[WeekOfYear] = SELECTEDVALUE('Slicer'[WeekNo])
)
)LastWeek_Total_CarsOnHand =
CALCULATE(
SUM('Work On Hand'[CarsOnHand]),
'Calendar'[WeekOfYear] = SELECTEDVALUE('Slicer'[WeekNo]) - 1, ALL('Calendar')
)LastWeek_Total_CarsCounted =
CALCULATE(
SUM('Daily Statistics'[CarsCounted]),
'Calendar'[WeekOfYear] = SELECTEDVALUE('Slicer'[WeekNo]) - 1, ALL('Calendar')
)
The three measures can then be used to perform the calculation steps you require:
Measure = 'Work On Hand'[Total_CarsOnHand] - 'Work On Hand'[LastWeek_Total_CarsOnHand] + 'Daily Statistics'[LastWeek_Total_CarsCounted]
The final result is shown below:
Best Regards,
Dino Tao
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.
This is fantastic, thank you @Anonymous !
Is there a way to have the filter based on my calendar table if I already have a field of "WeekOfYear"?
Hi @clock0928,
Of course you can, just change the
SELECTEDVALUE('Slicer'[WeekNo])
into
SELECTEDVALUE('Calendar'[WeekOfYear])
in the three DAXs, and I've tested them and they still work fine in my sample data.
Best Regards,
Dino Tao
@Anonymous love your work - thank you again for the assistance 🙂
Hi @clock0928 ,
I will start by showing you my test data:
To make it easier to see, I created a week table and used that to create a slicer:
I then used DAX to create the following three measures:
Total_CarsOnHand =
CALCULATE(
SUM('Work On Hand'[CarsOnHand]),
FILTER(
ALLSELECTED('Calendar'[WeekOfYear]),
'Calendar'[WeekOfYear] = SELECTEDVALUE('Slicer'[WeekNo])
)
)LastWeek_Total_CarsOnHand =
CALCULATE(
SUM('Work On Hand'[CarsOnHand]),
'Calendar'[WeekOfYear] = SELECTEDVALUE('Slicer'[WeekNo]) - 1, ALL('Calendar')
)LastWeek_Total_CarsCounted =
CALCULATE(
SUM('Daily Statistics'[CarsCounted]),
'Calendar'[WeekOfYear] = SELECTEDVALUE('Slicer'[WeekNo]) - 1, ALL('Calendar')
)
The three measures can then be used to perform the calculation steps you require:
Measure = 'Work On Hand'[Total_CarsOnHand] - 'Work On Hand'[LastWeek_Total_CarsOnHand] + 'Daily Statistics'[LastWeek_Total_CarsCounted]
The final result is shown below:
Best Regards,
Dino Tao
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.
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.