Formula to get average (mean) of all values that match name within last 90 days

lacexcel

New Member
Joined
Mar 4, 2020
Messages
17
Office Version
  1. 365
Platform
  1. Windows
Hi,

I have some data concerning supplier performance ratings and I'm looking for a formula to get an average 'Performance Rating' for each company within the last 90 days. I have done a fair amount of Googling but can't find a formula that performs the correct function.

The data is structured as follows (the first row of each sheet is used as headers):

Sheet 1 ("Individual Reviews"):
Column B - Date
Column E - Company
Column R - Performance Rating (%)

Sheet 2 ("Current Ratings"):
Column B - Company
Column C - Performance Rating (%)

Records are added manually into the 'Individual Reviews' sheet, with a formula to calculate the performance rating (for that specific record) as a percentage.

I'm looking for the 'Performance Rating' column in the 'Current Ratings' sheet to take an average (mean) of the performance ratings for all records in 'Individual Reviews' that match the company name given in each row in 'Current Ratings' within the last 90 days.

Any help would be greatly appreciated.

Many thanks,
Luke
 

Excel Facts

Fastest way to copy a worksheet?
Hold down the Ctrl key while dragging tab for Sheet1 to the right. Excel will make a copy of the worksheet.

etaf

Well-known Member
Joined
Oct 24, 2012
Messages
4,668
Office Version
  1. 365
Platform
  1. MacOS
averageIF() or averageIFS()

But how are the % calculated - taking an average is not always correct
Ie 10% say is 10/100
40% = 20/50
so average is 25%
=10020/100050
is 10.015
so not the same when using the quantities
 

lacexcel

New Member
Joined
Mar 4, 2020
Messages
17
Office Version
  1. 365
Platform
  1. Windows
Wayne,

Thanks for your response. I believe the percentages would be okay in my case, it shouldn't be an issue. In fairness, these could be changed to absolute values if necessary, as long as the final result for the overall rating is shown as a percentage.

I have tried both averageIF() and averageIFS() but to no avail. Would you mind giving an example of how this would be used in this context?

Thanks in advance,
Luke
 

etaf

Well-known Member
Joined
Oct 24, 2012
Messages
4,668
Office Version
  1. 365
Platform
  1. MacOS
this should work in C
=AVERAGEIFS('Individual review'!R:R,'Individual review'!E:E,Current!B2,'Individual review'!B:B,">="&TODAY()-90)

 

lacexcel

New Member
Joined
Mar 4, 2020
Messages
17
Office Version
  1. 365
Platform
  1. Windows
Fantastic, that worked! Thank you very much for your help.
 

etaf

Well-known Member
Joined
Oct 24, 2012
Messages
4,668
Office Version
  1. 365
Platform
  1. MacOS
you are welcome
 

Watch MrExcel Video

Forum statistics

Threads
1,129,697
Messages
5,637,870
Members
416,986
Latest member
zmartee

We've detected that you are using an adblocker.

We have a great community of people providing Excel help here, but the hosting costs are enormous. You can help keep this site running by allowing ads on MrExcel.com.
Allow Ads at MrExcel

Which adblocker are you using?

Disable AdBlock

Follow these easy steps to disable AdBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the icon in the browser’s toolbar.
2)Click on the "Pause on this site" option.
Go back

Disable AdBlock Plus

Follow these easy steps to disable AdBlock Plus

1)Click on the icon in the browser’s toolbar.
2)Click on the toggle to disable it for "mrexcel.com".
Go back

Disable uBlock Origin

Follow these easy steps to disable uBlock Origin

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back

Disable uBlock

Follow these easy steps to disable uBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back
Top