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

To celebrate FabCon Vienna, we are offering 50% off select exams. Ends October 3rd. Request your discount now.

Reply
Anonymous
Not applicable

Average of measure grouped by column

Hi everyone,

I want to create a graph showing the average of the measure Has_Licence for each country, so basically sum(Has_Licence) / distinctcount(Account). 

 

I've tried a bunch of different formulas I've found online, but they all simply return 1 for the accounts that have a licence and blank for the rest, whereas I want an average per country.

 

Relatively new to DAX and would be grateful if someone could help me. Thank you!

 

Unbenanntes Bild.png

1 ACCEPTED SOLUTION
tamerj1
Super User
Super User

Hi @Anonymous 
Please refer to attached sample file with the solution

1.png

Desired Outcome = 
AVERAGEX ( 
    CALCULATETABLE (
        VALUES ( 'Table'[Account] ),
        ALLEXCEPT ( 'Table', 'Table'[Country] )
    ),
    [Measure Has_Licence]
)

View solution in original post

4 REPLIES 4
tamerj1
Super User
Super User

Hi @Anonymous 
Please refer to attached sample file with the solution

1.png

Desired Outcome = 
AVERAGEX ( 
    CALCULATETABLE (
        VALUES ( 'Table'[Account] ),
        ALLEXCEPT ( 'Table', 'Table'[Country] )
    ),
    [Measure Has_Licence]
)
Anonymous
Not applicable

This worked! Thank you so much @tamerj1 and everyone else who contributed solutions 🙂

v-yueyunzh-msft
Community Support
Community Support

Hi , @Anonymous 

According to your description, you want to "Average of measure grouped by column".

Here are the steps you can refer to :
(1)This is my test data:

vyueyunzhmsft_0-1675387950880.png

(2)I create a measure like your Has_Licence:

Has_Licence = SUM('Table'[License])
 
(3)Then we can click "New Measure" to create a measure :

Average = var _t = SUMMARIZE(ALLSELECTED('Table') ,'Table'[Country],'Table'[Account],"Has_Licence" , [Has_Licence])
var _cur_country = MAX('Table'[Country])
var _sum =SUMX( FILTER(_t , [Country] = _cur_country) , [Has_Licence])
var _count =COUNTROWS(DISTINCT( SELECTCOLUMNS( FILTER(_t , [Country] = _cur_country) , "Account",[Account])))
return
DIVIDE(_sum,_count)

 

(4)Then we can put the fields on the visual and we can meet your need, the result is as follows:

vyueyunzhmsft_1-1675388227405.png

 

Thank you for your time and sharing, and thank you for your support and understanding of PowerBI! 

 

Best Regards,

Aniya Zhang

If this post helps, then please consider Accept it as the solution to help the other members find it more quickly

 

Greg_Deckler
Community Champion
Community Champion

@Anonymous This looks like a measure aggregation problem. See my blog article about that here: https://community.powerbi.com/t5/Community-Blog/Design-Pattern-Groups-and-Super-Groups/ba-p/138149

The pattern is:
MinScoreMeasure = MINX ( SUMMARIZE ( Table, Table[Group] , "Measure",[YourMeasure] ), [Measure])
MaxScoreMeasure = MAXX ( SUMMARIZE ( Table, Table[Group] , "Measure",[YourMeasure] ), [Measure])
AvgScoreMeasure = AVERAGEX ( SUMMARIZE ( Table, Table[Group] , "Measure",[YourMeasure] ), [Measure])
etc.



Follow on LinkedIn
@ me in replies or I'll lose your thread!!!
Instead of a Kudo, please vote for this idea
Become an expert!: Enterprise DNA
External Tools: MSHGQM
YouTube Channel!: Microsoft Hates Greg
Latest book!:
DAX For Humans

DAX is easy, CALCULATE makes DAX hard...

Helpful resources

Announcements
September Power BI Update Carousel

Power BI Monthly Update - September 2025

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

August 2025 community update carousel

Fabric Community Update - August 2025

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