Fabric is Generally Available. Browse Fabric Presentations. Work towards your Fabric certification with the Cloud Skills Challenge.
Hi All,
I'm currently running the following DAX code for a Running Total based on a calculated measure. I'm looking to optimise the below DAX code?
VAR _Date = MAX ('Fact_Table'[Date])
VAR _Date11 = EOMONTH (_Date, -11)
VAR _Date10 = EOMONTH (_Date, -10)
VAR _Date9 = EOMONTH (_Date, -9)
VAR _Value11 = CALCULATE([Head Count],
FILTER(
ALL('Fact_Table'), 'Fact_Table'[Date] = _Date11)
)
VAR _Value10 = CALCULATE([Head Count],
FILTER(
ALL('Fact_Table'), 'Fact_Table'[Date] = _Date10)
)
VAR _Value9 = CALCULATE([Head Count],
FILTER(
ALL('Fact_Table'), 'Fact_Table'[Date] = _Date9)
)
RETURN _Value11 + _Value10 + _Value9 + [Head Count]
Example of results below:
Thanks.
Solved! Go to Solution.
Hi, @GillyGils
You can try the following methods.
Measure:
Running Head Count = SUMX(FILTER(ALL('Table'),[Date]<=SELECTEDVALUE('Table'[Date])),[Head Count])
Is this the result you expect?
Best Regards,
Community Support Team _Charlotte
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.
@GillyGils Use a date table and try like. Date table's date should be joined with date of your table. Use date/month from date table in visual, slicer and measures
CALCULATE([Head Count],filter(allselected(date),date[date] <=max(date[Date])))
or
Cumm Based on Date = CALCULATE([Head Count], Window(1,ABS,0,REL, ALLSELECTED('date'[date]),ORDERBY('Date'[date],ASC)))
or
CALCULATE([Head Count],filter(all(date),date[date] <=max(date[Date])))
or
Cumm Based on Date = CALCULATE([Head Count], Window(1,ABS,0,REL, all('date'[date]),ORDERBY('Date'[date],ASC)))
Running Total/ Cumulative:
https://www.youtube.com/watch?v=h2wsO332LUo&list=PLPaNVDMhUXGaaqV92SBD5X2hk3TMNlHhb&index=42
Power BI Window function Rolling, Cumulative/Running Total, WTD, MTD, QTD, YTD, FYTD: https://youtu.be/nxc_IWl-tTc
Thanks for the response.
In my fact table, its only monthly data. So I only have month end dates so which are a whole number in which ive converted to 'Date'. Is there a solution to not have a date table included?
Hi, @GillyGils
You can try the following methods.
Measure:
Running Head Count = SUMX(FILTER(ALL('Table'),[Date]<=SELECTEDVALUE('Table'[Date])),[Head Count])
Is this the result you expect?
Best Regards,
Community Support Team _Charlotte
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.
Check out the November 2023 Power BI update to learn about new features.
Read the latest Fabric Community announcements, including updates on Power BI, Synapse, Data Factory and Data Activator.