Skip to main content
cancel
Showing results for 
Search instead for 
Did you mean: 

Earn the coveted Fabric Analytics Engineer certification. 100% off your exam for a limited time only!

Reply
sbharti
New Member

Getting Average of averages as a new column

I have a requirement from business wherein I need to show average of averages in a new column. My data is almost similar to the image below:emp.csvemp.csv

Now, I have created report wherein I have a filter through which we can select Q1 or Q2. Once a question is selected, we need to show average of that question for each employee. That was easy for me, with a new measure as:

 

Each_AVG = SWITCH(SELECTEDVALUE(QList[QNO]), "Q1", AVERAGE(Emp[Q1]), AVERAGE((Emp[Q2])))

This works fine and I get an output as:

 

Power BI ReportPower BI Report

Now, I don't need to show total, but a new column which shows average of averages. The above total is not what we need, not the overall average value.. But I need to add a new measure as a column in above which shows  (2.5+1.67+3.00)/3 = 2.39

 

I am able to display 2.33 using AverageX but just can't figure out how to show this average of averages..

 

Any help would be greatly appreciated.

 

Thanks

1 ACCEPTED SOLUTION

Oh yes, very possible.  Use a measure like this and add it to your table:

Avg of AVG = 
    AVERAGEX(
        SUMMARIZE(ALL(Employee),Employee[Name],"Average", [AVG]),
        [Average]
    )

This will evaluate against all names whenever your original [AVG] evaluates.  If you have other filters on your data, you may want to use ALLEXCEPT to keep those applied.

 

 

 

View solution in original post

7 REPLIES 7
v-cherch-msft
Employee
Employee

Hi @sbharti 

You may use ISFILTERED function to change the total.For example:

Measure = IF(ISFILTERED(Emp[Name]),[Each_AVG],AVERAGEX(ALL(Emp[Name]),Emp[Each_AVG]))

Regards,

Community Support Team _ Cherie Chen
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

This doesn't work for me. From this formula I am able to get average of averages at the bottom, where the total is shown.

 

However, I need to add a new column to the tabular visualization which just shows one value, the average of averages. Is that possible?

 

The solution by Ashish works for me in this dummy data report. But when I implement that on the actual report I just get the same individual averages on each row.

 

I am really stuck at this point. 

Do you want the Average of Averages value displayed once, or in each row of data?

 

For each row of data, you would use a measure and add that to your table.  If you only want it displayed once,  your best bet is to make the same measure and display it in a card, and try to match the formatting to your table.

 

 

If you could make a mockup of what your desired result would look like in Excel, we could give better info.

I have input data as below:

 

image.png

 

There are other Q values like Q2, Q3... which will be chosen by a filter.  I then need to display each employee's individual average for the question selected in slicer. I can get that done by below code:

 

AVG = SWITCH(SELECTEDVALUE(QList[QNO]), "Q1", AVERAGEX(Employee,[Q1]), AVERAGEX(Employee,[Q2]))

Now, in the tabular report, I need to display the average of averages, something like below:

 

image.png

 

If you note the average of averages is = (2.5+2.33+2.33)/3

 

By using below measure, what I get is an overall average, by summing all values in a question and dividing by count of values:

 

AVERAGEX(ALLSELECTED(Employees) , Employees[AVG])

How can I get this done.. It is something very straightforward in SQL like:

 

SELECT name, AVERAGE(AVG) FROM (
SELECT name, AVERAGE(q1) AS AVG FROM Employee
GROUP BY name) temp

 

Do you think its possible?

 

 

Oh yes, very possible.  Use a measure like this and add it to your table:

Avg of AVG = 
    AVERAGEX(
        SUMMARIZE(ALL(Employee),Employee[Name],"Average", [AVG]),
        [Average]
    )

This will evaluate against all names whenever your original [AVG] evaluates.  If you have other filters on your data, you may want to use ALLEXCEPT to keep those applied.

 

 

 

Dear Cmcmahan,

 

That was perfect. It resolved the issue.

 

Thank you so much..

Ashish_Mathur
Super User
Super User

Hi,

Try this measure

=AVERAGEX(ALL(Data[Name]),[Each_Avg])

Hope this helps.


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

Helpful resources

Announcements
April AMA free

Microsoft Fabric AMA Livestream

Join us Tuesday, April 09, 9:00 – 10:00 AM PST for a live, expert-led Q&A session on all things Microsoft Fabric!

March Fabric Community Update

Fabric Community Update - March 2024

Find out what's new and trending in the Fabric Community.