Need a formula to average the most recent X # of data points, non-contiguous cells & w/ blanks

Marc Wilson

New Member
Joined
Jul 7, 2015
Messages
1
Excel ver. 2010, 32-bit
OS Windows 7 Pro, 32-bit, Service pack 1

Normally I can find what I'm looking for online or on the boards but this one has me stumped. My actual sheet has hundreds of rows and columns but here is a simple example illustrating my challenge:

Below is a table of students and their test scores and quiz scores this year. I want a formula that will return an average of the 3 most recent test scores for each student.

Test/QuizMichaelDavidCaraTyshawn
Test 5909195
Quiz 5887290
Test 488828582
Quiz 492937979
Test 3738670
Quiz 3759075
Test 2758890
Quiz 2688579
Test 18591
Quiz 18290

<tbody>
</tbody>

I have bolded the test scores since that's all we're interested in. The ideal formula will be something I can fill right as far as I need to go (I understand about relative references so no need to add the $'s).

The correct answers for the formula will be:
Michael: 84.33
David: 82.00
Cara: 86.33
Tyshawn: 82.33

As you can see, I have two challenges.

First, there are blank cells to deal with, and the blanks are not distributed evenly across rows, meaning that the students have different combinations of rows representing the three most recent tests.

Second, there is quiz data interspersed that I don't want to capture, so I can't just use a range of contiguous cells.

The formula I'm looking for would look just at rows 2, 4, 6, 8, and 10 and return the average of the uppermost three cells which contain values.

As I mentioned, my actual sheet is much more complicated, so adjusting the cells in the formula for each column, and updating those adjustments whenever I add new rows, isn't feasible.

Any help would be greatly appreciated. Thanks!
 

Excel Facts

Did you know Excel offers Filter by Selection?
Add the AutoFilter icon to the Quick Access Toolbar. Select a cell containing Apple, click AutoFilter, and you will get all rows with Apple
There probably is an easier way, but this CSE formula should work:

{=AVERAGE(IF(NUMBERVALUE(RIGHT($A$2:$A$11,LEN($A$2:$A$11)-5))>=LARGE(IF(LEFT($A$2:$A$11,4)="Test",IF(LEN(B2:B11)>0,NUMBERVALUE(RIGHT($A$2:$A$11,LEN($A$2:$A$11)-5)))),3),IF(LEN(B2:B11)>0,IF(LEFT($A$2:$A$11,4)="Test",B2:B11))))} Confirmed with CTRL + SHIFT + ENTER (not just ENTER)

Don't include the Braces {}. They will show up when you confirm
 
Last edited:
Upvote 0
Row\Col
A​
B​
C​
D​
E​
1​
Test/QuizMichaelDavidCaraTyshawn
2​
Test 5
90
91
95
3​
Quiz 5
88
72
90
4​
Test 4
88
82
85
82
5​
Quiz 4
92
93
79
79
6​
Test 3
73
86
70
7​
Quiz 3
75
90
75
8​
Test 2
75
88
90
9​
Quiz 2
68
85
79
10​
Test 1
85
91
11​
Quiz 1
82
90
12​
84.333333​
82​
86.3333​
82.333333​

Average of most recent 3 tests...

B12, control+shift+enter, not just enter, and copy across:
Rich (BB code):

=AVERAGE(IF(IF(MOD(ROW(B$2:B$11)-ROW(B$2),2)=0,
    ROW(B$2:B$11))<=SMALL(IF(ISNUMBER(1/B$2:B$11),
    IF(MOD(ROW(B$2:B$11)-ROW(B$2),2)=0,ROW(B$2:B$11))),3),
    IF(ISNUMBER(1/B$2:B$11),B$2:B$11)))
 
Upvote 0
Note that my formula requires "Test 1", "Test 2" etc. (no custom test names) while Aladin's requires alternating test, quiz, test, quiz etc.

I very much like Aladin's use of ISNUMBER(1/...) That will exclude any extraneous entries (null values, 0, spaces, alpha characters, etc.)
 
Last edited:
Upvote 0

Forum statistics

Threads
1,213,546
Messages
6,114,251
Members
448,556
Latest member
peterhess2002

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