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

Get certified in Microsoft Fabric—for free! For a limited time, get a free DP-600 exam voucher to use by the end of 2024. 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
November Carousel

Fabric Community Update - November 2024

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

Live Sessions with Fabric DB

Be one of the first to start using Fabric Databases

Starting December 3, join live sessions with database experts and the Fabric product team to learn just how easy it is to get started.

Las Vegas 2025

Join us at the Microsoft Fabric Community Conference

March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount! Early Bird pricing ends December 9th.

Nov PBI Update Carousel

Power BI Monthly Update - November 2024

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

Top Solution Authors