cancel
Showing results for 
Search instead for 
Did you mean: 
Reply
Girish_P
Frequent Visitor

Get sum for all rows but Average in grand total in matrix visual

In a matrix visual I want to change the Grand Total field to Grand Average. For example.

 

Screenshot 2020-11-26 123154.jpg

 

2 ACCEPTED SOLUTIONS

Hi @Girish_P ,

 

Modify your measure as below:

avg1z = 
var _sum=SUMX(FILTER(ALL(Sheet1),'Sheet1'[Day]=MAX('Sheet1'[Day])&&'Sheet1'[Row Labels]=MAX('Sheet1'[Row Labels])),'Sheet1'[qnt])
var _distinctcount=CALCULATE(DISTINCTCOUNT(Sheet1[Row Labels]),FILTER(ALL(Sheet1),'Sheet1'[Day]=MAX('Sheet1'[Day])))
Return
IF(ISINSCOPE(Sheet1[Row Labels]),_sum,DIVIDE(SUMX(FILTER(ALL(Sheet1),'Sheet1'[Day]=MAX('Sheet1'[Day])),'Sheet1'[qnt]),_distinctcount))

And you will see:

v-kelly-msft_0-1606787192471.png

For the related .pbix file,pls see attached.

 

 

 

Best Regards,
Kelly

Did I answer your question? Mark my post as a solution!

View solution in original post

Hi,

Total = SUM(Sheet1[qnt])
Measure = AVERAGEX(VALUES(Sheet1[Row Labels]),[Total])

Hope this helps.

Untitled.png

Try these measures

 


Regards,
Ashish Mathur
http://www.ashishmathur.com
https://www.linkedin.com/in/excelenthusiasts/

View solution in original post

7 REPLIES 7
Girish_P
Frequent Visitor

@amitchandak @sreenub 

 

pbix download 

https://1drv.ms/u/s!AuHFzkBFHhqqga9TApvSulUpiJ9hwA?e=HANo68 

 

Thanks for your replies. but the solution is not clear. attaching test pbix for your reference. can you please implement and post it. 

 

Hi  @Girish_P ,

 

Create a measure as below:

avg1 = IF(ISINSCOPE(Sheet1[Row Labels]),MAX('Sheet1'[qnt]),AVERAGEX(FILTER(ALL(Sheet1),'Sheet1'[Day]=MAX('Sheet1'[Day])),'Sheet1'[qnt]))

And you will see:

v-kelly-msft_0-1606718318242.png

 

For the related .pbix file,pls see attached.

 

Best Regards,
Kelly

Did I answer your question? Mark my post as a solution!

@v-kelly-msft  thanks for your reply.

 

but looks like its taking Max at row level instead of sum.

 

pbix link :..

 

https://1drv.ms/u/s!AuHFzkBFHhqqga9YJ1zS6nva_EK7-A?e=kYVcQj

Hi,

Total = SUM(Sheet1[qnt])
Measure = AVERAGEX(VALUES(Sheet1[Row Labels]),[Total])

Hope this helps.

Untitled.png

Try these measures

 


Regards,
Ashish Mathur
http://www.ashishmathur.com
https://www.linkedin.com/in/excelenthusiasts/

View solution in original post

Hi @Girish_P ,

 

Modify your measure as below:

avg1z = 
var _sum=SUMX(FILTER(ALL(Sheet1),'Sheet1'[Day]=MAX('Sheet1'[Day])&&'Sheet1'[Row Labels]=MAX('Sheet1'[Row Labels])),'Sheet1'[qnt])
var _distinctcount=CALCULATE(DISTINCTCOUNT(Sheet1[Row Labels]),FILTER(ALL(Sheet1),'Sheet1'[Day]=MAX('Sheet1'[Day])))
Return
IF(ISINSCOPE(Sheet1[Row Labels]),_sum,DIVIDE(SUMX(FILTER(ALL(Sheet1),'Sheet1'[Day]=MAX('Sheet1'[Day])),'Sheet1'[qnt]),_distinctcount))

And you will see:

v-kelly-msft_0-1606787192471.png

For the related .pbix file,pls see attached.

 

 

 

Best Regards,
Kelly

Did I answer your question? Mark my post as a solution!

View solution in original post

amitchandak
Super User IV
Super User IV

@Girish_P ,

Try measure like

avergageX(values(Table[Row Label]),[Day1])

 

avergageX(values(Table[Row Label]),sum(Table[Day1]))



Did I answer your question? Mark my post as a solution! Appreciate your Kudos!!
Dashboard of My Blogs !! YouTube Channel !! Connect on Linkedin

Proud to be a Super User!

sreenub
Resolver II
Resolver II

Create the measure which  is showing values (10,20,30 ...) with  Average instead of SUM. so it will show 10,20,30 ... remain same since it is lowest level of granularity   and  it will show Average  at grand total .

Helpful resources

Announcements
PBI User Groups

Welcome to the User Group Public Preview

Check out new user group experience and if you are a leader please create your group!

MBAS on Demand

Microsoft Business Applications Summit sessions

On-demand access to all the great content presented by the product teams and community members! #MSBizAppsSummit #CommunityRocks

MBAS Attendee Badge

Claim Your Badge & Digital Swag!

Check out how to claim yours today!

secondImage

Are You Ready?

Test your skills now with the Cloud Skills Challenge.

Top Solution Authors