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

The Power BI Data Visualization World Championships is back! Get ahead of the game and start preparing now! Learn more

Reply
Yiyi
Helper I
Helper I

How to calculate the average of values in a calculated column?

Hello all, 

 

I am new to DAX and I am totally stuck in calculating an dynamic average value for a calculated column. 

 

The calculated column for my table: 

 

Distinct Companies per Headline = CALCULATE(DISTINCTCOUNT('Main Data'[Company]), ALLEXCEPT('Main Data', 'Main Data'[HeadlineID]))

 

The table with the column: 

HeadlineID CompanyDistinct companies per headline 
2113A2
2113B2
2114C1
2115D

1

Now I would like to calculate the average of distinct companies per headline. 

The expected result would be:  Average = (2+1+1)/3  because HeadlineID 2113 is 2 times in the list. 

 

I tried to use summazie to create a new table so that only distinct headlineID and distinct companies per headline will be included. But it doesn't work. Can you help me in this? Thank you a lot! 

 

Average_Distinct_Companies_per_Headline = 
VAR SummaryTable =
    SUMMARIZE(
        'Data',
        'Data'[HeadlineID],  
        "Distinct_Companies_per_Headline",
        CALCULATE(DISTINCTCOUNT('Main Data'[Company]), ALLEXCEPT('Main Data', 'Main Data'[HeadlineID]))
    )
RETURN
    AVERAGEX(SummaryTable, [Distinct_Companies_per_Headline])

 

1 ACCEPTED SOLUTION

Ah, yes, I thought that was a measure. Try

Average_Distinct_Companies_per_Headline =
AVERAGEX (
    VALUES ( 'Main Data'[HeadlineID] ),
    CALCULATE (
        DISTINCTCOUNT ( 'Main Data'[Company] ),
        ALLEXCEPT ( 'Main Data', 'Main Data'[HeadlineID] )
    )
)

View solution in original post

4 REPLIES 4
johnt75
Super User
Super User

Try

Average_Distinct_Companies_per_Headline =
AVERAGEX (
    VALUES ( 'Main Data'[HeadlineID] ),
    [Distinct Companies per Headline]
)

Thanks for your time!

For some reason I am not able to select [Distinct Companies per Headline] in the calculation. I wonder is it because this column is a calculated column. The DAX only allows to select measures here. 

Ah, yes, I thought that was a measure. Try

Average_Distinct_Companies_per_Headline =
AVERAGEX (
    VALUES ( 'Main Data'[HeadlineID] ),
    CALCULATE (
        DISTINCTCOUNT ( 'Main Data'[Company] ),
        ALLEXCEPT ( 'Main Data', 'Main Data'[HeadlineID] )
    )
)

Looks good now, thanks a lot!

Helpful resources

Announcements
November Power BI Update Carousel

Power BI Monthly Update - November 2025

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

Fabric Data Days Carousel

Fabric Data Days

Advance your Data & AI career with 50 days of live learning, contests, hands-on challenges, study groups & certifications and more!

FabCon Atlanta 2026 carousel

FabCon Atlanta 2026

Join us at FabCon Atlanta, March 16-20, for the ultimate Fabric, Power BI, AI and SQL community-led event. Save $200 with code FABCOMM.