Microsoft Fabric Community Conference 2025, March 31 - April 2, Las Vegas, Nevada. Use code FABINSIDER for a $400 discount.
Register nowGet inspired! Check out the entries from the Power BI DataViz World Championships preliminary rounds and give kudos to your favorites. View the vizzies.
Basically I've made a running total chart of a count of organizations (column: "AccountName") who have signed an agreement with my company (column: "DateAgreementSigned) - see screenshot at the bottom. Where I need help is the fact that some of these organizations cancel the agreement on a certain date (column: DateAccountExited). So, the organization needs to be counted in the running total up until they have an exit day and after that date not to be counted.
The way the information is structured in PowerBI is as follows- there is an accounts table that contains the name and agreement start/exit dates. I created a separate date table that has all of the calendar dates from the year 2000-2025. I set a many to one active relationship between the DateAgreementSigned column and the Date column in the date table. I did this so even in years where another agreement may not have been signed, it will still show a number instead of omitting the year (especially if I have the chart broken down by month & year).
Here is the DAX code for the running total measure that is being used in the "Value" field for the chart:
RunningTotal = CALCULATE( COUNTA('accounts'[AccountName]), FILTER ( ALL ( 'Date'[Date] ), 'Date'[Date] <= MAX ('Date'[Date]) ) )
The "axis" field for the chart is simply the Year column from the date table.
Current running total chart:
Solved! Go to Solution.
Hi @lwbenso
You could create a measure that calculates RunningTotal = Cumulative Signed - Cumulative Exited
One way to do this would be:
RunningTotal = CALCULATE ( VAR AccountsSigned = COUNTROWS ( accounts ) VAR AccountsExited = CALCULATE ( COUNTROWS ( accounts ), USERELATIONSHIP ( accounts[DateAccountExited], 'Date'[Date] ) ) RETURN AccountsSigned - AccountsExited, DATESBETWEEN ( 'Date'[Date], BLANK (), MAX ( 'Date'[Date] ) ) )
Notes on the measure:
Regards,
Owen 🙂
Try this:
RunningTotal = CALCULATE( COUNTROWS('accounts'), 'accounts'[DateAccountExited] = BLANK(), FILTER ( ALL ( 'Date'[Date] ), 'Date'[Date] <= MAX ('Date'[Date]) ) )
Now you're telling Power BI to only look at rows that do NOT have an Exit date. If there's an exit date, it will be removed from the calculation.
COUNTROWS() is typically faster than COUNTA().
@Anonymousthat is closer to what I am looking for, but would it be possible to leave them in the count until the exit date is reached (rather than take them out all together)?
Also- thanks for the tip on using COUNTROWS()
Bump...maybe someone else has a tip?
Hi @lwbenso
You could create a measure that calculates RunningTotal = Cumulative Signed - Cumulative Exited
One way to do this would be:
RunningTotal = CALCULATE ( VAR AccountsSigned = COUNTROWS ( accounts ) VAR AccountsExited = CALCULATE ( COUNTROWS ( accounts ), USERELATIONSHIP ( accounts[DateAccountExited], 'Date'[Date] ) ) RETURN AccountsSigned - AccountsExited, DATESBETWEEN ( 'Date'[Date], BLANK (), MAX ( 'Date'[Date] ) ) )
Notes on the measure:
Regards,
Owen 🙂
March 31 - April 2, 2025, in Las Vegas, Nevada. Use code FABINSIDER for a $400 discount!
Check out the February 2025 Power BI update to learn about new features.
User | Count |
---|---|
84 | |
70 | |
66 | |
50 | |
31 |
User | Count |
---|---|
116 | |
99 | |
75 | |
65 | |
40 |