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

Power BI is turning 10! Let’s celebrate together with dataviz contests, interactive sessions, and giveaways. Register now.

Reply
Jimmy17
New Member

Average of the lowest 40

I have been tryng to create a measure that calculates the average of the 'best' 40 results from site A by period. Lower scores are better and zero represents no score and needs to be ignored. Sample data below. There are hundreds of scores per period at site A. Can anyone help? Please 🙂 

 

SitePeriodScore
A1001.7
A1001.65
A1001.55
A1001.6
B1000
A1001.59
A1011.45
A1011.55
A1011.75
A1011.55
A1011.9
B1010
B1011.75

 

1 ACCEPTED SOLUTION
_MG_
Frequent Visitor

Hey Jimmy17. 
You could first create a calculated column which counts the values which are lower than the value in the current row. 
Something like this should work: 

Rank =
VAR ScoreCurrentRow = Score[Score]
VAR SiteCurrentRow = Score[Site]
VAR PeriodCurrentRow = Score[Period]
return COUNTROWS(FILTER(Score, Score[Score] < ScoreCurrentRow && SiteCurrentRow = Score[Site] && PeriodCurrentRow = Score[Period] &&  Score[Score] <> 0 )) + 1
_MG__0-1652276712567.png

 


After this you could create a measure which calculates the average over the site and the period, but only over the top 40 (In my example it was 2):
AVG = CALCULATE(AVERAGE(Score[Score]), Score[Score] <> 0, Score[Rank] <= 2)
_MG__1-1652276743399.png

 


I hope this will help you. 


View solution in original post

1 REPLY 1
_MG_
Frequent Visitor

Hey Jimmy17. 
You could first create a calculated column which counts the values which are lower than the value in the current row. 
Something like this should work: 

Rank =
VAR ScoreCurrentRow = Score[Score]
VAR SiteCurrentRow = Score[Site]
VAR PeriodCurrentRow = Score[Period]
return COUNTROWS(FILTER(Score, Score[Score] < ScoreCurrentRow && SiteCurrentRow = Score[Site] && PeriodCurrentRow = Score[Period] &&  Score[Score] <> 0 )) + 1
_MG__0-1652276712567.png

 


After this you could create a measure which calculates the average over the site and the period, but only over the top 40 (In my example it was 2):
AVG = CALCULATE(AVERAGE(Score[Score]), Score[Score] <> 0, Score[Rank] <= 2)
_MG__1-1652276743399.png

 


I hope this will help you. 


Helpful resources

Announcements
Join our Fabric User Panel

Join our Fabric User Panel

This is your chance to engage directly with the engineering team behind Fabric and Power BI. Share your experiences and shape the future.

June 2025 Power BI Update Carousel

Power BI Monthly Update - June 2025

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

June 2025 community update carousel

Fabric Community Update - June 2025

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