Join us at FabCon Atlanta from March 16 - 20, 2026, for the ultimate Fabric, Power BI, AI and SQL community-led event. Save $200 with code FABCOMM.
Register now!The Power BI Data Visualization World Championships is back! Get ahead of the game and start preparing now! Learn more
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 | Company | Distinct companies per headline |
| 2113 | A | 2 |
| 2113 | B | 2 |
| 2114 | C | 1 |
| 2115 | D | 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])
Solved! Go to 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] )
)
)
Try
Average_Distinct_Companies_per_Headline =
AVERAGEX (
VALUES ( 'Main Data'[HeadlineID] ),
[Distinct Companies per Headline]
)
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!
The Power BI Data Visualization World Championships is back! Get ahead of the game and start preparing now!
Check out the November 2025 Power BI update to learn about new features.
| User | Count |
|---|---|
| 20 | |
| 11 | |
| 10 | |
| 4 | |
| 4 |
| User | Count |
|---|---|
| 34 | |
| 32 | |
| 19 | |
| 12 | |
| 10 |