cancel
Showing results for 
Search instead for 
Did you mean: 
Reply
xliu1
Helper II
Helper II

Percentage of Subtotal in Matrix visualizations

I need to make a matrix visualizations that show the percentage of subtotal as below

xliu1_0-1633022178604.png

Rows: Course_Level (undergraduate vs. graduate)

          Course_Site (On Campus, High Flex, Off Campus)

Columns: College

Values: % of subtotal (for example: 82% of undergraduate course sections are on campus)

I created a new variable using the formula: 

ModalityPerc = DIVIDE(SUM(Aggr_Headcount[Section_Count]), CALCULATE(SUM(Aggr_Headcount[Section_Count]), Aggr_Headcount[Course_LEVEL]))
 
But when I placed the variable "ModalityPerc" for values, I got this error  
xliu1_1-1633022920375.png

 

Any idea on how I should modify the formula to make it work? Thanks.

 

1 ACCEPTED SOLUTION
mattww
Responsive Resident
Responsive Resident

Ah ok, you would need to add the school into the ALLEXCEPT too 

 

Section_Total =
CALCULATE (
SUM ( Aggr_Headcount[Section_Count] ),
ALLEXCEPT ( Aggr_Headcount, Aggr_Headcount[Course_LEVEL],Aggr_Headcount[School] )
)

So anything you want the measure to continue to be filtered by, such as the level or school goes in the second part of that except.  

 

You could then use that in your % calc

 

ModalityPerc =
DIVIDE ( SUM ( Aggr_Headcount[Section_Count] ), [Section_Total] )

 

View solution in original post

5 REPLIES 5
mattww
Responsive Resident
Responsive Resident

The reason you're getting this error is because of the part highlighted in red below. The second part of a CALCULATE should be some kind of filter which would return a true/false, for example Aggr_Headcount[Course_LEVEL] > 10

ModalityPerc = DIVIDE(SUM(Aggr_Headcount[Section_Count]), CALCULATE(SUM(Aggr_Headcount[Section_Count]), Aggr_Headcount[Course_LEVEL]))

If this post helps then please consider Accept it as the solution to help the other members find it more quickly.

Thanks for your response. Course_Level only includes two values "undergraduate" and "graduate".

I try to make the formula dynamic, so it will calculate the % of subtotal for each category of course level

mattww
Responsive Resident
Responsive Resident

Try this

 

Section_Total =
CALCULATE (
SUM ( Aggr_Headcount[Section_Count] ),
ALLEXCEPT ( Aggr_Headcount, Aggr_Headcount[Course_LEVEL] )
)

This would give you the bottom number of your divide

 

If this post helps then please consider Accept it as the solution to help the other members find it more quickly.

 

Matt

Thank you. I tried your formula, but it returns the same value as shown below?

xliu1_0-1633027512457.png

 

 

mattww
Responsive Resident
Responsive Resident

Ah ok, you would need to add the school into the ALLEXCEPT too 

 

Section_Total =
CALCULATE (
SUM ( Aggr_Headcount[Section_Count] ),
ALLEXCEPT ( Aggr_Headcount, Aggr_Headcount[Course_LEVEL],Aggr_Headcount[School] )
)

So anything you want the measure to continue to be filtered by, such as the level or school goes in the second part of that except.  

 

You could then use that in your % calc

 

ModalityPerc =
DIVIDE ( SUM ( Aggr_Headcount[Section_Count] ), [Section_Total] )

 

Helpful resources

Announcements
2022 Release Wave 1 760x460.png

2022 Release Wave 1 Plan

Power Platform release plan for the 2022 release wave 1 describes all new features releasing from April 2022 through September 2022.

Power BI December 2021 Update_carousel 768x460.jpg

Check it Out!

Click here to read more about the December 2021 Updates!

Top Solution Authors