Average is a simple calculation. But sometimes, there is more to explore. Let’s go through this topic and implement these calculations in Power BI.

Introduction
I learned how to calculate an Average at school: Take a bunch of numbers, create a sum over them, then divide the result by the count of numbers, and you’re done.
This calculation sounds very easy.

I discovered a few days ago that there could be much more in an average calculation than expected.
In this article, I’ll show you some variants of the average calculation. Then I switch to Power BI to perform these Calculations in DAX.
Do you mind doing some math?
Let’s look at the following table with invented sales data:

I want to calculate the average value of orders by Country and year. In the end, I would like to calculate an average overall.
OK, then let’s divide the values in the column Sales Amount by the Order Count:

Now the creepy question: How should I calculate the Total?
Calculating the Average
It turns out that there are two ways, which leads to two different results.
To shorten the table, I filter the table by 2019 alone:

The first average (549.81) is the average of all values in the column "Average Order Value".
The second average (550.81) is calculated by dividing the Total Sales Amount by the Total Order Count.
Which one is correct?
Well, both are correct. It depends on what you want to calculate.
While the first is the simple average of the four values, the second average is weighted by the order count per Country. The higher the order count is in one Country, the greater this Country’s influence on the result.
Let’s look at 2020 for a better example of the weighted average:

Here you can see that the second average is higher than the first because the order count for the United States is the highest by a large margin. Consequently, the higher order count in the United States has a more significant influence on the result.
I will call this result "Weighted Average".
You have to use the first average if you want to eliminate the weight of the Order Count. Let’s call it the "Unweighted Average".
Wait, we are not finished yet.
Add additional weight to the Average
Sometimes, you need to manipulate the calculation by adding a Weight or Rank to the data.

I introduced the column "Importance" to manipulate the result.
This column marks which Country has the highest importance and must influence the result.
We will use the following formula to calculate the result:
Total Sales Amount = SUM(Sales Amount * Importance)
Total Order Count = SUM(Order Count * Importance)
Afterwards, we can calculate the Average to get the result.
Here is the Result:

As you can see, the weighted average result is much lower than before, as we used the column "Importance" to manipulate each Country’s weight. As France and Italy have the highest importance, the value is nearer to their Average Order Value.
The unweighted average is the same as the relation between the Sales Amount, and the Order Count stay the same. Even after the multiplication with the importance.
A weight factor is a proper method to emphasize the importance or relevance of parts of your data with an aspect of your choice.
Now we can switch to Power BI and implement these calculations in Dax.
Implementation in Power BI
Weighted Average
We can implement the Weighted Average with a simple Measure:
Average Sales Amount per Order =
DIVIDE( [Online Sales (By Customer)]
,[Order Count (By Customer)]
)

The Filter Context makes sure that the calculation of the Total Average is correct:
934’403’814.18 / 486’949 = 1’918.894
Unweighted Average
However, the calculation of the unweighted average is a different story.
My first thought was to pre-calculate all averages and, afterwards, calculate the average from them.
The Measure must recognize if the Filter Context contains a Country and if yes, it has to divide the Sales Amount by the Order Count.
After some time, I found out that we can resolve this problem in DAX with the following Measure:
Average per Country =
AVERAGEX(VALUES('Geography'[Region Country])
,DIVIDE([Online Sales (By Customer)]
,[Order Count (By Customer)] )
)
The result looks like this:

When you export this table to Excel, you can calculate the Average Sales Amount per Order, and you will get 14’183.83.
The tricky part comes when you want to add the State to the table:

When you export the table now, the result of an average will be different.
We have to add a new Measure to the model to get the correct result:
Average per Country and State =
AVERAGEX(SUMMARIZE('Geography'
,'Geography'[Region Country]
,'Geography'[State Province])
,DIVIDE([Online Sales (By Customer)]
,[Order Count (By Customer)] )
)
This Measure will calculate the correct value for each Country and State, and at the total level:

Again, both Measures are correct. It depends on which result is expected by your users. You have to talk to your Stakeholders to clarify this question in advance.
Average with a weight column
Now I want to add a rank to define the Importance of each Country. The higher the Rank, the higher is the influence of this Country on the result.
I added an arbitrary ranking column to each Country for this calculation. Each Country has a rank between 1 and 6:

Now I need to include the Rank in the calculation:
Average using Rank =
VAR SalesAmount = SUMX('Online Sales'
,'Online Sales'[SalesAmount] *
RELATED('Customer'[Country Rank])
)
VAR OrderCount = SUMX('Online Sales'
,'Online Sales'[First Order Line Count] *
RELATED('Customer'[Country Rank])
)
RETURN
IF(HASONEVALUE('Customer'[Region Country])
,[Average Sales Amount per Order]
,DIVIDE(SalesAmount, OrderCount)
)
Let’s start from the bottom of this Measure:
I’m using IF(HASONEVALUE(‘Customer'[Region Country]) to check If the current Filter context contains one or more Countries.
If the current Filter Context contains one Country only, I can use the Measure [Average Sales Amount per Order] to calculate the Average per Country. This Measure works very well and delivers the correct value per Row. In this case, it doesn’t matter if you add the States or Cities to the Report. The result is the same.
As soon as the current Filter Context contains more than one Country, I need to calculate the Weighted Average using the Rank per Country.
I do this calculation by using SUMX to multiple the Sales Amount of each transaction in the Online Sales table with the Country Rank.
The following picture shows the result with all Measures:

As you can see, all results on the Total line differ from one another as expected.
Caution: This is an example of one possible approach and doesn’t show a definitive solution. Depending on your data and requirements, your solution can differ from mine.
Other possible approaches
It could be a good idea to prepare a DAX table with pre-calculated results if you need to prepare the Measure for one specific scenario.
The Contoso Data model, used in my example, contains 12 million rows in the Online Sales table and less than 20’000 rows in the Customer Table. The Matrix used in this example takes less than one second to compute the results.
Your data can contain more data and, therefore, may be slower than my example.
In such a case, a DAX table is a viable solution. The drawback of this approach is that other Tables cannot filter the result, for example, Product Groups. If you need this, you need to define the relationships required and prepare the DAX table accordingly.
Take care that adding such columns can unexpectedly alter the result.
Conclusion
When I started writing this article, I had the solution with the DAX table in mind, as it looked easy to prepare.
But I wouldn’t say I liked it, as this approach added several constraints regarding the possibility of filtering the results.
When I searched for possible ways to calculate a weighted average, I found this Website: How to Calculate Weighted Average on wikiHow
While applying this approach to my example data in Excel, the result confused me. After talking with a colleague, which is a mathematician, we found different ways to calculate an average.
Even though I was already in the middle of this article, I restarted writing this article with my new knowledge.
Anyway, I was surprised to find out that I can calculate the average differently to get different meanings. This discovery opened a new world to me, as I need to start discussions with my clients about this as well.

My life was not complicated enough until now. Sigh …
If you appreciate my work, feel free to support me through
Or scan this QR Code:

Any support is greatly appreciated.
Thank you.