cancel
Showing results for 
Search instead for 
Did you mean: 
Reply
Microsoft
Microsoft

Average based on distinct values in another column

I have created a Table Visualization that counts the distinct values for a given unique id. I would like the average of the number of distinct values per unique id. 

 

This is what my raw data looks like.

Unique IDValue
1A
1B
2A
2A
3C

 

And the table visualization I want would look like this. Right now the table is only visualizing the Total Number of unique ids. 

 

Unique IDDistinct Values
12
21
31
Average1.333333

 

Is there a way to get the average from the table visualization? Or should I create a new measure?

 

Thanks!

1 ACCEPTED SOLUTION
Solution Sage
Solution Sage

Hi @melz63017. You can get the average to display in the totals row:

 

DistinctValues.PNG

 

To get the Distinct Values measure, I started with a couple of building blocks, shown above as the first two measures.

 

DistinctCountValue = DISTINCTCOUNT(TableName[Value])

 

DistinctCountUniqueID = DISTINCTCOUNT(TableName[Unique ID])

 

The last measure in the table is the Distinct Values measure, which uses both of the building blocks defined above:

 

Distinct Values = IF(
	HASONEVALUE(TableName[Unique ID]), 
[DistinctCountValue],
SUMX(VALUES(TableName[Unique ID]), [DistinctCountValue]) / [DistinctCountUniqueID]
)

 

 

The HASONEVALUE function at the beginning of the IF statement checks if your current evaluation context has more than one distinct Unique ID value. So on the table rows that show one Unique ID each, there's one value. For a totals row, there would be multiple values (as long as you don't have your table filtered to a single Unique ID anyway).

 

So whenever we're on a non-totals row, the measure will do the standard calculation for the DistinctCountValue. If we're on a totals row, it will use SUMX to get the sum of each DistinctCountValue when your table is at the UniqueID level, i.e., add up 2 + 1 + 1 to get 4 in this case. Divide that by the number of count of unique IDs, and you get to 1.33.

View solution in original post

3 REPLIES 3
Solution Sage
Solution Sage

Hi @melz63017. You can get the average to display in the totals row:

 

DistinctValues.PNG

 

To get the Distinct Values measure, I started with a couple of building blocks, shown above as the first two measures.

 

DistinctCountValue = DISTINCTCOUNT(TableName[Value])

 

DistinctCountUniqueID = DISTINCTCOUNT(TableName[Unique ID])

 

The last measure in the table is the Distinct Values measure, which uses both of the building blocks defined above:

 

Distinct Values = IF(
	HASONEVALUE(TableName[Unique ID]), 
[DistinctCountValue],
SUMX(VALUES(TableName[Unique ID]), [DistinctCountValue]) / [DistinctCountUniqueID]
)

 

 

The HASONEVALUE function at the beginning of the IF statement checks if your current evaluation context has more than one distinct Unique ID value. So on the table rows that show one Unique ID each, there's one value. For a totals row, there would be multiple values (as long as you don't have your table filtered to a single Unique ID anyway).

 

So whenever we're on a non-totals row, the measure will do the standard calculation for the DistinctCountValue. If we're on a totals row, it will use SUMX to get the sum of each DistinctCountValue when your table is at the UniqueID level, i.e., add up 2 + 1 + 1 to get 4 in this case. Divide that by the number of count of unique IDs, and you get to 1.33.

View solution in original post

Hi,

 

Thanks for the help. Is there a way just to show the measure (i.e. Average)? It doesn't have to show up in place of Total but I was wondering if there was formula to just get the measure. 

 

Thanks!

 

Melissa

Once the measure's created, you can drag it anywhere. You can use the one already created for the table visual, or just use the last part of that formula. If I take this version of the measure:

 

Distinct Values = SUMX(VALUES(TableName[Unique ID]), [DistinctCountValue]) / [DistinctCountUniqueID]

 

I can drop that on the report in a visual, like a card, and get this:

 

Measure.PNG

Helpful resources

Announcements
secondImage

Experience what’s next for Power BI

Join us for an in-depth look at the new Power BI features and capabilities at the free Microsoft Business Applications Launch Event.

secondImage

Power BI Women

Join our monthly meetings and learning sessions.

secondImage

Congratulations!

We are excited to announce the Power BI Super Users!

secondImage

The largest Power BI virtual conference

100+ sessions, 100+ speakers, Product managers, MVPs, and experts. All about Power BI. Attend online or watch the recordings.

Top Solution Authors
Top Kudoed Authors