Return last occurrence of values in a column

Markeus

New Member
Joined
Dec 2, 2014
Messages
36
Hi,

I am trying to return the last set of numbers in a column so that I can average a different set of numbers in a second column. Here's what I mean:

0
5
06
15
17
11
05
15
11
19
06

<tbody>
</tbody>

I would like to average the values beside the last occurrence of 1 (5,1,9). I think I can probably figure out how to do the averaging easily enough but I'd like to know how to return the 5,1,9 by looking up the last occurrence of the series of 1's. The fact that there are three 1's is arbitrary and for example purposes. The number of 1's (and corresponding values in second column) will vary from case to case.

thanks for any help.
 

Excel Facts

Can you sort left to right?
To sort left-to-right, use the Sort dialog box. Click Options. Choose "Sort left to right"
so you want to find 2 or 3 or 4 identical numbers in column A

let us say you want three 1's as per your example

do you want every set of three 1's considered or only the last set found
 
Upvote 0
only the last set found.

In reality the data is for when a valve is open and flow data. 1 represents the valve being open and the value in the second column is the flow rate past the valve while open. I want to find an average flow for the most recent occurrence of the valve being open. The software snaps a data point every 5 minutes and the amount of time the valve is open is arbitrary. Thus why there could be multiple rows of 1 and corresponding flow data.
 
Upvote 0
Row\Col
A​
B​
C​
D​
E​
F​
1​
XYlengthendpointavg
2​
0
5
3​
9​
5​
3​
0
6
4​
1
5
5​
1
7
6​
1
1
7​
0
5
8​
1
5
9​
1
1
10​
1
9
11​
0
6

D2, control+shift+enter, not just enter:
Rich (BB code):

=LOOKUP(9.9999999999999E+307,
    1/FREQUENCY(IF(A2:A11=1,ROW(A2:A11)),IF(1-(A2:A11=1),ROW(A2:A11))),
    FREQUENCY(IF(A2:A11=1,ROW(A2:A11)),IF(1-(A2:A11=1),ROW(A2:A11))))

E2, just enter:
Rich (BB code):

=LOOKUP(9.99999999999999E+307,1/(A2:A11=1),ROW(A2:A11)-ROW(A2)+1)

F2, just enter:
Rich (BB code):

=AVERAGE(OFFSET(INDEX(B2:B11,E2),0,0,-D2))
 
Last edited:
Upvote 0

Forum statistics

Threads
1,214,642
Messages
6,120,701
Members
448,980
Latest member
CarlosWin

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