Join us at FabCon Atlanta from March 16 - 20, 2026, for the ultimate Fabric, Power BI, AI and SQL community-led event. Save $200 with code FABCOMM.
Register now!Get Fabric Certified for FREE during Fabric Data Days. Don't miss your chance! Request now
Hello,
I am having trouble with using a date slicer to calculate starting balance for a cash balance.
So, I want to have a date filter that will allow me to calculate a dinamic starting and end balance.
- Starting balance is calculated as Movements in period previous to the Start Date (Date From).
- End balance is calculated as Starting balance + movements in between selected period.
The date slicer will ideally be a range (Date From to Date To), where, if I change the start date, my opening balance will increase/decrease.
I include below a simple table and the expected results, in case it helps with understanding what I would love to achieve.
| Date | Value |
| 01/01/2019 | 50 |
| 01/06/2019 | 100 |
| 31/12/2019 | -20 |
Based on these values, some calculated examples will be:
Start date: 05/01/2019. End date: 30/06/2020.
Starting Balance: 50
Movements: +80
End Balance: 130
Start date: 01/09/2019. End date: 30/06/2020.
Starting Balance: 150
Movements: -20
End Balance: 130
Do you have any guidance I could use?
Thanks a lot!!
Solved! Go to Solution.
Ok we can do this with 3 measures. I've made some assumptions, such as that you have a date table.
Movements = SUM('YourData'[Value])Start Balance = var StartDate = FIRSTDATE('Date Table'[Date])
var output = CALCULATE(
[Movements],
ALL('YourData'),
'YourData'[Date] < StartDate
)
RETURN
outputEnd Balance = var movements = [Movements]
var startBalance = [Start Balance]
RETURN
startBalance + movements
You make sure you have date calendar. End balance is nothing but cumulative
Starting value =
var _min =minx(Table,Table[date]))
CALCULATE(SUM(Table[value]),filter(date,date[date] <=_min)
Cumm value = CALCULATE(SUM(Table[value]),filter(date,date[date] <=maxx(date,date[date])))
Cumm value = CALCULATE(SUM(Table[value]),filter(date,date[date] <=maxx(date,endofmonth(dateadd(date[date]),-1,month))))
To get the best of the time intelligence function. Make sure you have a date calendar and it has been marked as the date in model view. Also, join it with the date column of your fact/s. Refer :
https://radacad.com/creating-calendar-table-in-power-bi-using-dax-functions
https://www.archerpoint.com/blog/Posts/creating-date-table-power-bi
https://www.sqlbi.com/articles/creating-a-simple-date-table-in-dax/
Appreciate your Kudos.
Ok we can do this with 3 measures. I've made some assumptions, such as that you have a date table.
Movements = SUM('YourData'[Value])Start Balance = var StartDate = FIRSTDATE('Date Table'[Date])
var output = CALCULATE(
[Movements],
ALL('YourData'),
'YourData'[Date] < StartDate
)
RETURN
outputEnd Balance = var movements = [Movements]
var startBalance = [Start Balance]
RETURN
startBalance + movements
Hello @Anonymous , that worked great!
Thanks a lot!!
Check out the November 2025 Power BI update to learn about new features.
Advance your Data & AI career with 50 days of live learning, contests, hands-on challenges, study groups & certifications and more!