Starting December 3, join live sessions with database experts and the Microsoft product team to learn just how easy it is to get started
Learn moreGet certified in Microsoft Fabric—for free! For a limited time, get a free DP-600 exam voucher to use by the end of 2024. Register now
Hello,
I have data that looks like this:
Employee | Employment | Age |
1 | a | 35 |
1 | b | 35 |
2 | a | 40 |
3 | a | 35 |
4 | a | 51 |
4 | b | 51 |
I want to calculate the average age of the individual employees. All I know how to do is average the age column, but the obviously counts Employee 1 and 4's ages twice, giving me an average age of 41.2.
I need a measure that counts distinct values in the employee column, then averages their ages. This should give me an average age of 40.3.
Any idea about a formula that could do this?
Thanks!
Solved! Go to Solution.
This should work (tested locally):
Measure = AVERAGEX(SUMMARIZE(Table1, Table1[Employee], Table1[Age]), Table1[Age])
Hi @bullius,
You can also create the measure using the formula.
Measure = AVERAGEX(VALUES(Table[Employee]), CALCULATE(AVERAGE(Table[Age])))
Thanks,
Lydia Zhang
Hi @bullius,
You can also create the measure using the formula.
Measure = AVERAGEX(VALUES(Table[Employee]), CALCULATE(AVERAGE(Table[Age])))
Thanks,
Lydia Zhang
Hi Lydia,
I am facing similar issue and your measure helped me a lot however In my case i need the average based on selection of three different slicers, i can see you have used one slicer with values (employees)in above measure. how about if I have three such values (three columns) that needs to be make averages of averages.
Thanks for the solutions!
This should work (tested locally):
Measure = AVERAGEX(SUMMARIZE(Table1, Table1[Employee], Table1[Age]), Table1[Age])
Awesome. Thanks a lot, it helped me.
Hello, older thread but taking a chance here... I have a very similar scenario, except that I need to include a additional parameter to the equation. To continue with the OP's example, I would also have another column for the employee gender, and need a formula that will calculate the average age of Male employees. How can this be done?
Thanks.
Try adding in a FILTER clause, e.g.
AVERAGEX ( SUMMARIZE ( FILTER ( Table1, Table1[Gender] = "Male" ), Table1[Employee], Table1[Age] ), Table1[Age] )
Hey Jahida,
This looks like it can solve an issue that i'm experiencing.
However, how could it work if the column "Employee" is in another table?
And would it be any different if it's not neccessarily a number, but text?
I'm not really sure what you mean... the original question wanted an average, what's an average of text values? Also if the columns are in different tables, how are they associated?
Right....it's a bit more complicated than i thought 🙂
Let's say i have 3 tables.
Table 1 - TransactionID - gives me the information about the transaction. Date, time, etc. ID is always unique. Details not included in the example - only ID
Transaction ID
1 |
2 |
3 |
4 |
5 |
Table 2 - Transaction - Details of what items the transaction included, always referencing the ID, but extending over multiple rows, depending on the size of the transaction.
Transaction ID Item
1 | Banana |
1 | Turnip |
1 | Chair |
1 | Banana |
1 | Banana |
1 | Apple |
2 | Turnip |
2 | Cabbage |
2 | Apple |
3 | Banana |
3 | Cucumber |
3 | Turnip |
4 | Banana |
5 | Chair |
Table 3 - Item ID - Extended information about the items that summarizes them in categories.
Item ID Item Category
11 | Banana | Fruit |
12 | Turnip | Vegetable |
13 | Chair | Furniture |
14 | Apple | Fruit |
15 | Cabbage | Vegetable |
16 | Cucumber | Vegetable |
From the below screenshot, what i care about is the Distinct count for the Item Categories, meaning that i don't need to know how many of them are in total, but how many Transactions include which of the Categories (thus the DistinctCount, using Measure = DISTINCTCOUNT)
What i'm looking to find is the Average of each category Per Transaction. I want to be able to track the categories with the largest average per transaction (as well as the one with the lowest, and see trends, etc.)
So if i'm correct, that'd mean that the Average for Furniture should be 0.4 (2/5), Vegetables would be 0.6 (3/5) and Fruits would be 0.8 (4/5).
I have the feeling that this is very simple and it's a little bit that i'm missing, but i just can't get the right formulas to work for this.
The .pbix mock file can be found here, if needed.
Any help/tips will be appreciated!
Thanks!
First of all, that was a really good clarification post, thank you for making it easy to understand your situation.
I think the measure that you had (DISTINCTCOUNT) was close, what you wanted was just some way to divide by total transactions. There's probably a few ways to do this, I'm a bit rusty so the first one that came to my mind was using CALCULATE. Here's the measure I used:
Measure 2 = DISTINCTCOUNT('Transaction'[Transaction ID])/CALCULATE(DISTINCTCOUNT('Transaction'[Transaction ID]), ALL('ItemID'[Category]))
Note that the first bit is the same as your measure, and then you divide it by the count of transactions across all categories. It gives the results you said were the expected (you might need to delete and remake your measure so it reformats). I hope that helps!
Amazing! This is exactly what i was looking for!
Thanks for your help, especially considering this is already a solved topic and you won't get the credit 😉
Have a lovely weekend ahead and holidays if you're celebrating!
Haha no problem, glad to help. Like I said, you made it easy. Happy Holidays to you too!
Starting December 3, join live sessions with database experts and the Fabric product team to learn just how easy it is to get started.
March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount! Early Bird pricing ends December 9th.
User | Count |
---|---|
90 | |
88 | |
83 | |
64 | |
49 |
User | Count |
---|---|
127 | |
108 | |
87 | |
70 | |
66 |