Microsoft Fabric Community Conference 2025, March 31 - April 2, Las Vegas, Nevada. Use code MSCUST for a $150 discount.
Register nowThe Power BI DataViz World Championships are on! With four chances to enter, you could win a spot in the LIVE Grand Finale in Las Vegas. Show off your skills.
Hello All,
I want to calculate % of Total & Cumulative % for the fields in the matrix. As we drill down or drill up i.e from Category --> SubCategory or vice versa the values should be shown accordingly. It will be really helpful if someone can suggest the logic for the same. I am using a sample superstore dataset.
Regards,
Nidhi
Solved! Go to Solution.
Hi,
I am not sure if I understood your question correctly, but please check the below picture and the attached pbix file.
I tried to create a sample pbix file like below.
I hope the below can provide some ideas on creating a solution for your data model.
Sales measure: =
SUM( Sales[Sales] )
Sales cumulate percentage: =
VAR _sales = [Sales measure:]
VAR _subcategorycumulatesales =
CALCULATE (
[Sales measure:],
FILTER (
ALL ( Category ),
Category[Category] = MAX ( Category[Category] )
&& [Sales measure:] >= _sales
)
)
VAR _subcategoryallsales =
CALCULATE ( [Sales measure:], ALLEXCEPT ( Category, Category[Category] ) )
VAR _categorycumulatesales =
CALCULATE (
[Sales measure:],
FILTER ( ALL ( Category[Category] ), [Sales measure:] >= _subcategoryallsales )
)
VAR _categoryallsales =
CALCULATE ( [Sales measure:], ALL ( Category ) )
RETURN
SWITCH (
TRUE (),
ISINSCOPE ( Category[Subcategory] ), DIVIDE ( _subcategorycumulatesales, _subcategoryallsales ),
DIVIDE ( _categorycumulatesales, _categoryallsales )
)
Sales percentage: =
VAR _sales = [Sales measure:]
VAR _subcategoryallsales =
CALCULATE ( [Sales measure:], ALLEXCEPT ( Category, Category[Category] ) )
VAR _categoryallsales =
CALCULATE ( [Sales measure:], ALL ( Category ) )
RETURN
SWITCH (
TRUE (),
ISINSCOPE ( Category[Subcategory] ), DIVIDE ( _sales, _subcategoryallsales ),
DIVIDE ( _subcategoryallsales, _categoryallsales )
)
If this post helps, then please consider accepting it as the solution to help other members find it faster, and give a big thumbs up.
Hi,
I am not sure if I understood your question correctly, but please check the below picture and the attached pbix file.
I tried to create a sample pbix file like below.
I hope the below can provide some ideas on creating a solution for your data model.
Sales measure: =
SUM( Sales[Sales] )
Sales cumulate percentage: =
VAR _sales = [Sales measure:]
VAR _subcategorycumulatesales =
CALCULATE (
[Sales measure:],
FILTER (
ALL ( Category ),
Category[Category] = MAX ( Category[Category] )
&& [Sales measure:] >= _sales
)
)
VAR _subcategoryallsales =
CALCULATE ( [Sales measure:], ALLEXCEPT ( Category, Category[Category] ) )
VAR _categorycumulatesales =
CALCULATE (
[Sales measure:],
FILTER ( ALL ( Category[Category] ), [Sales measure:] >= _subcategoryallsales )
)
VAR _categoryallsales =
CALCULATE ( [Sales measure:], ALL ( Category ) )
RETURN
SWITCH (
TRUE (),
ISINSCOPE ( Category[Subcategory] ), DIVIDE ( _subcategorycumulatesales, _subcategoryallsales ),
DIVIDE ( _categorycumulatesales, _categoryallsales )
)
Sales percentage: =
VAR _sales = [Sales measure:]
VAR _subcategoryallsales =
CALCULATE ( [Sales measure:], ALLEXCEPT ( Category, Category[Category] ) )
VAR _categoryallsales =
CALCULATE ( [Sales measure:], ALL ( Category ) )
RETURN
SWITCH (
TRUE (),
ISINSCOPE ( Category[Subcategory] ), DIVIDE ( _sales, _subcategoryallsales ),
DIVIDE ( _subcategoryallsales, _categoryallsales )
)
If this post helps, then please consider accepting it as the solution to help other members find it faster, and give a big thumbs up.
@NidhiBhusari , based on what I got example
Cumm Sales % = divide( CALCULATE(SUM(Sales[Sales Amount]),filter(all('Date'),'Date'[date] <=max('Date'[date]))), CALCULATE(SUM(Sales[Sales Amount]) , all()) )
or
Cumm Sales % = divide( CALCULATE(SUM(Sales[Sales Amount]),filter(allselected('Date'),'Date'[date] <=max('Date'[date]))), CALCULATE(SUM(Sales[Sales Amount]) , allselected()) )
User | Count |
---|---|
136 | |
73 | |
73 | |
58 | |
54 |
User | Count |
---|---|
194 | |
95 | |
63 | |
63 | |
51 |