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

Find everything you need to get certified on Fabric—skills challenges, live sessions, exam prep, role guidance, and more. Get started

Reply
tsf
Helper I
Helper I

Calculate Average of Averages

I want to get the average of a series of averages, but can't figure it out. Here's my data:

DAX_AverageProblem.png

The circled value of 132.05 is the average of the total transactions / total workers (2509 / 19 = 132.05). But instead I need the average of the Average/Day *daily* values. In other words, it should be 29.52. How would I go about getting that? Thanks.

 

(BTW, I realize 19 is listed as the total # of workers even though every day shows only 17. I suspect at this point that is because the workers each day are not always the same, and therefore the total distinct count of workers across the 5 days is actually 19.)

2 ACCEPTED SOLUTIONS
austinsense
Impactful Individual
Impactful Individual

This is a great question - based on what you're saying you'll need to 1) figure out the average for each day and 2) then average those averages.  In the future, it's helpful if you share your DAX in your question.

 

To do this you need to use the AVERAGEX function.

  • The first argument is a table that you will iterate over all the rows - in your case you want a table of all the days.  If you have a table that already has one row for every day then use that, otherwise you may want to use the VALUES function to ensure that you get just one row for every day.
  • The second argument is the expression you want to calculate for every row of the table - in your case the average number of transactions for that day.  For the second argument you may need to use CALCULATE depending on the expression.
The final result of the function is the average of the result from each row.  This is the way that all the "X" functions work - SUMX, AVERAGEX, STDEVX, etc.
Austin is VP Operations at PowerPivotPro and a professional self-service enthusiast 🙂

View solution in original post

itchyeyeballs
Impactful Individual
Impactful Individual

The AvergageX function should give you what you need, something like

 

AverageX(values(tablename[colname]),[Average/Day Measure])

View solution in original post

4 REPLIES 4
itchyeyeballs
Impactful Individual
Impactful Individual

The AvergageX function should give you what you need, something like

 

AverageX(values(tablename[colname]),[Average/Day Measure])

Thanks to both of you. Very helpful. The VALUES function was the key as I had already been trying the AVERAGEX function without success. I had seen (and probably even used) the Values function before, but haven't spent enough time getting familiar with all the DAX functions.

greggyb
Resident Rockstar
Resident Rockstar

The average of averages is usually the wrong way to approach this sort of problem. I'd rather take [Transactions] / [Worker-Days] for the top level average.

 

Let's imagine the following sample data:

Day  |  Workers  |  Transactions  |  Average/Day

1  |  1  |  10  |  10

2  |  2  |  40  |  20

 

The average of averages is (10 + 20) / 2 = 15. Transactions / Worker-Days is (10+40) / 3 = 16.7. Here we have 3 workers. 2 of them are able to process 20 transactions/day. 1 of them is only able to do 10/day. The 10/day worker is the outlier here.

 

Imagine adding a third row:

Day  |  Workers  |  Transactions  |  Average/Day

1  |  1  |  10  |  10

2  |  2  |  40  |  20

3  |  5  |  105  | 21

 

Average of averages: (10 + 20 + 21) / 3 = 17

Transactions / worker-days: (10 + 40 + 105) / (1 + 2 + 5) = 19.4

Here, it's clear that the typical worker gets ~20 transactions / day, but the average of averages method understates average productivity by >10%.

 

Average of averages overstates the impact of outliers.

 

To get transactions over worker-days you can simply replace your [Average/Day] measure:

 

// DAX
// Measure

Worker-Days =
COUNTROWS(
    SUMMARIZE(
        'FactTransaction'
        ,'FactTransaction'[WorkerKey]
        ,'FactTransaction'[Date]
    )
)

Average/Day = 
DIVIDE( [Transactions], [Worker-Days] )

SUMMARIZE() groups by the fields named, navigating relationships from the base table identified in the first argument. Thus, it gives us a table made up of the unique combinations of workers and days. When a single day is in context (one of your detail rows from the sample in your original post), this will be the same as the distinct number of workers on that day. [Average/Day] is thus the same for the detail level.

 

At the total level, we use the appropriate numerator and denominator and get a much more accurate result.

austinsense
Impactful Individual
Impactful Individual

This is a great question - based on what you're saying you'll need to 1) figure out the average for each day and 2) then average those averages.  In the future, it's helpful if you share your DAX in your question.

 

To do this you need to use the AVERAGEX function.

  • The first argument is a table that you will iterate over all the rows - in your case you want a table of all the days.  If you have a table that already has one row for every day then use that, otherwise you may want to use the VALUES function to ensure that you get just one row for every day.
  • The second argument is the expression you want to calculate for every row of the table - in your case the average number of transactions for that day.  For the second argument you may need to use CALCULATE depending on the expression.
The final result of the function is the average of the result from each row.  This is the way that all the "X" functions work - SUMX, AVERAGEX, STDEVX, etc.
Austin is VP Operations at PowerPivotPro and a professional self-service enthusiast 🙂

Helpful resources

Announcements
Sept PBI Carousel

Power BI Monthly Update - September 2024

Check out the September 2024 Power BI update to learn about new features.

September Hackathon Carousel

Microsoft Fabric & AI Learning Hackathon

Learn from experts, get hands-on experience, and win awesome prizes.

Sept NL Carousel

Fabric Community Update - September 2024

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