AVERAGEIFS for last X records in a customer list?

GaryV

New Member
Joined
Mar 23, 2018
Messages
14
I have a dataset that looks a bit like this:

Cust A1/1/18345
Cust A2/1/18634
Cust A3/1/18567
Cust B11/1/181209
Cust B12/1/181340
Cust B1/1/181500
Cust B2/1/181654
Cust B3/1/181567
Cust C2/1/18423
Cust C3/1/18450
Cust D3/1/181690

<tbody>
</tbody>

The record count can vary by customer. I'm looking to average the 3rd column's numbers, for up to the last 3 rows, by customer.

I have a separate list of unique customer ID's and I've been experimenting with AVERAGEIFS, Offset, etc., but can't seem to get the logic correct.

Could I kindly ask for an experts view on this and for any recommendations on a solution?

Many thanks!!
G
 

Excel Facts

Select all contiguous cells
Pressing Ctrl+* (asterisk) will select the "current region" - all contiguous cells in all directions.
Hi, set up your shet like the image here:

https://drive.google.com/open?id=1DK5lnq7osu8VQxBaWFNm2IJOYmJyZQb6

In F3, put the following array formula (Make sure to enter the formula with CTRL+SHIFT+ENTER, so that curly brackets {} appear at either end in the formula bar on top of the screen. You can't put type them in yourself!)

=AVERAGE(INDEX(C1:C11,N(IF(1,LARGE(IF(--(A1:A11=F1)*C1:C11<>0,ROW(A1:A11)),ROW(INDIRECT("1:"&F2,1)))))))
 
Upvote 0
Control+shift+enter, not just enter:
Rich (BB code):
=AVERAGE(IF(ROW(C2:C12)>=LARGE(IF(A2:A12="Cust A",IF(ISNUMBER(C2:C12),IF(C2:C12>0,ROW(C2:C12)))),
    MIN(3,COUNTIFS(A2:A12,"Cust A",C2:C12,">0"))),IF(A2:A12="Cust A",IF(ISNUMBER(C2:C12),IF(C2:C12>0,C2:C12)))))
 
Upvote 0
That's an interesting way how to do it. but why do you need the isnumber, and also not use cell refrences for the criteria?

Also, it would be interesting to see the difference in calculation time between the 2
 
Upvote 0
Control+shift+enter, not just enter:
Rich (BB code):
=AVERAGE(IF(ROW(C2:C12)>=LARGE(IF(A2:A12="Cust A",IF(ISNUMBER(C2:C12),IF(C2:C12>0,ROW(C2:C12)))),
    MIN(3,COUNTIFS(A2:A12,"Cust A",C2:C12,">0"))),IF(A2:A12="Cust A",IF(ISNUMBER(C2:C12),IF(C2:C12>0,C2:C12)))))

By the way, The >0 test is probably not required.
Rich (BB code):
=AVERAGE(IF(ROW(C2:C12)>=LARGE(IF(A2:A12="Cust A",IF(ISNUMBER(C2:C12),ROW(C2:C12))),
     MIN(3,COUNTIFS(A2:A12,"Cust A"))),IF(A2:A12="Cust A",IF(ISNUMBER(C2:C12),C2:C12))))
 
Upvote 0
Can't thank you enough Dave and Aladin, I'll take a poke at this and see if my fumbling fingers can get your code into my spreadsheet! thanks again!!! :)

G
 
Upvote 0
Thanks Gents! Dave I wound up using your snippet for its ability to handle all customer names. I had a few challenges with the array formula and realized it didn't like having a header row at the top. But I have it functioning just as I want it, thanks again!!!

G
 
Upvote 0
Thanks Gents! Dave I wound up using your snippet for its ability to handle all customer names. I had a few challenges with the array formula and realized it didn't like having a header row at the top. But I have it functioning just as I want it, thanks again!!!

G

Let F2 or any other cell house a condition (customer) like Cust A and adjust the formula you are given:

Rich (BB code):
=AVERAGE(IF(ROW($C$2:$C$12)>=LARGE(IF($A$2:$A$12=F2,IF(ISNUMBER($C$2:$C$12),ROW($C$2:$C$12))),
    MIN(3,COUNTIFS($A$2:$A$12,F2))),IF($A$2:$A$12=F2,IF(ISNUMBER($C$2:$C$12),$C$2:$C$12))))

which has "the ability to handle all customer names" as you put it.
 
Upvote 0
Thanks, I probably missed something in my translation and will check again today, but the averages did not calc correctly when I had a header row...
 
Upvote 0

Forum statistics

Threads
1,215,730
Messages
6,126,527
Members
449,316
Latest member
sravya

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