Moving AVERAGEIF with OFFSET

Kev4022

New Member
Joined
Jun 20, 2015
Messages
6
Good Afternoon,

My data is constantly updated (new rows) and i'd like to be able to average the last 3 scores (SCORE) for each Student (STUDENT) - in the example below Student A would show an average of 91, 71, 74. The issue arises when I add new data, I need this to update on the fly. This is an inherited system and cannot change the layout in anyway.

Edit: This is the formula I've been trying to play with:
=AVERAGEIF(A:A, "A", OFFSET(B2,COUNT(B:B),0,-3,1))

Edit 2: I am keen on learning so if you have time to explain any answers that would be great! As with the above formula I'm trying to follow it logically with the Range, Criteria and Average Range but clearly I'm failing somewhere!

Any help would be much appreciated!


STUDENTSCORE
A100
A91
B55
D62
A71
C68
A74

<tbody>
</tbody>
 
Last edited:

Excel Facts

Which Excel functions can ignore hidden rows?
The SUBTOTAL and AGGREGATE functions ignore hidden rows. AGGREGATE can also exclude error cells and more.
This works i believe but requires CTRL-SHIFT-ENTER:

=AVERAGE(IF((A2:A100="A")*(ROW(2:100)=LARGE((A2:A100="A")*ROW(2:100),{1,2,3})),B2:B100))

Its a little bit complicated so the explanation I haven't really got the time for. It essentially produces 3 arrays to test against the first array and produces an array of FALSE and 3 numerical answers. AVERAGE will ignore the FALSE parts so produce an average of the 3 values (or less if you only had 2 'A' s for example.
 
Upvote 0
This works i believe but requires CTRL-SHIFT-ENTER:

=AVERAGE(IF((A2:A100="A")*(ROW(2:100)=LARGE((A2:A100="A")*ROW(2:100),{1,2,3})),B2:B100))

Its a little bit complicated so the explanation I haven't really got the time for. It essentially produces 3 arrays to test against the first array and produces an array of FALSE and 3 numerical answers. AVERAGE will ignore the FALSE parts so produce an average of the 3 values (or less if you only had 2 'A' s for example.

Genius! Thank you so much! My laptop is no longer in danger of annihilation!
 
Upvote 0
Just make sure the size of the range is always greater than your data in terms of number of rows to test or you are going to get incorrect result, ie change the 100 in the formula to suit the amount of data you are ever likely to get. Using full columns would work but that's a slow formula then.
 
Upvote 0

Forum statistics

Threads
1,214,915
Messages
6,122,214
Members
449,074
Latest member
cancansova

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
Back
Top