Starting December 3, join live sessions with database experts and the Microsoft product team to learn just how easy it is to get started
Learn moreGet certified in Microsoft Fabric—for free! For a limited time, get a free DP-600 exam voucher to use by the end of 2024. Register now
Hello, can you help me?
I would like to calculate the cumulative percentage of sales of my salespeople.
The expected result would be the yellow column.
If it had a date it would be easier, but my table is just that information, name of the seller and sales.
Link excel with formula and data.
Solved! Go to Solution.
You are going to need some way to know how to accumulate. I added an index column in Power Query (Add Column menu, Index.) Just make sure your data is sorted the way you want before you add the index. You are right, a date would make this easier, but the Index works just fine. I am not aware of a way to add such an index in DAX, and adding an index is a modeling issue anyway, so that really is best done in Power Query when possible.
Cumulative Percent =
VAR varCurrentIndex =
MAX( 'Table'[Index] )
VAR varGrandTotal =
SUMX(
ALL( 'Table' ),
'Table'[sales]
)
VAR varCumulativeTotal =
SUMX(
FILTER(
ALL( 'Table' ),
'Table'[Index] <= varCurrentIndex
),
'Table'[sales]
)
VAR Result =
DIVIDE(varCumulativeTotal,varGrandTotal,0)
RETURN
Result
DAX is for Analysis. Power Query is for Data Modeling
Proud to be a Super User!
MCSA: BI ReportingYou are going to need some way to know how to accumulate. I added an index column in Power Query (Add Column menu, Index.) Just make sure your data is sorted the way you want before you add the index. You are right, a date would make this easier, but the Index works just fine. I am not aware of a way to add such an index in DAX, and adding an index is a modeling issue anyway, so that really is best done in Power Query when possible.
Cumulative Percent =
VAR varCurrentIndex =
MAX( 'Table'[Index] )
VAR varGrandTotal =
SUMX(
ALL( 'Table' ),
'Table'[sales]
)
VAR varCumulativeTotal =
SUMX(
FILTER(
ALL( 'Table' ),
'Table'[Index] <= varCurrentIndex
),
'Table'[sales]
)
VAR Result =
DIVIDE(varCumulativeTotal,varGrandTotal,0)
RETURN
Result
DAX is for Analysis. Power Query is for Data Modeling
Proud to be a Super User!
MCSA: BI Reporting@edhans
Ouw, Perfect. So it worked perfectly, thank you very much. Would it be that instead of using the index, using rank in dax would work?
Maybe, but you would have to deal with the issues of a tie, which could be handled with the DENSE vs SKIP flag in RANKX. But it will for sure make the DAX more complex and possibly slow down the model depending on how many you are doing. 4-5, or 400-500 won't matter. If you get in to the thousands or tens of thousands, you'll see using RANKX start to slow things down for your visuals if used this way.
And I assume you know it would always do cumulative totals from highest to lowest (or reversed) vs how the data comes in.
DAX is for Analysis. Power Query is for Data Modeling
Proud to be a Super User!
MCSA: BI ReportingStarting December 3, join live sessions with database experts and the Fabric product team to learn just how easy it is to get started.
March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount! Early Bird pricing ends December 9th.
User | Count |
---|---|
92 | |
86 | |
84 | |
66 | |
49 |
User | Count |
---|---|
140 | |
113 | |
106 | |
64 | |
60 |