Lookup 2nd most recent date for specific person and return corresponding value

pacerfan07

New Member
Joined
Jun 2, 2017
Messages
20
I have the following on Sheet1 below. On Sheet2 I just have everyone's Name listed once in column A (John, Kate, and Jim). In column B of Sheet2 I would like to look at the name from column A and see if it matches column A on Sheet1. If it does, then lookup the 2nd most recent occurrence in column B and return the corresponding values in column C. For example John should return 18.

Thanks!

ABC
1John11/1/1710
2John11/2/1715
3Kate11/1/1714
4John11/3/1718
5Kate11/2/1720
6Jim11/1/1725
7Kate11/3/1730
8Kate11/4/1740
9Jim11/1/1720
10John11/4/1760

<tbody>
</tbody>
 

Excel Facts

Ambidextrous Undo
Undo last command with Ctrl+Z or Alt+Backspace. If you use the Undo icon in the QAT, open the drop-down arrow to undo up to 100 steps.
1] Assume your Input table located in Sheet1 A1:C10

2] Output table located in Sheet2, criteria in A1:A3 enter: " John", "Kate" and " Jim"

3] In Sheet2, B1 enter formula and copied down :

=INDEX(Sheet1!C$1:C$10,AGGREGATE(14,6,ROW(Sheet1!C$1:C$10)/(Sheet1!B$1:B$10<>"")/(Sheet1!A$1:A$10=A1),2))

Regards
Bosco
 
Last edited:
Upvote 0
Sheet1 (data)

John11/1/201710
John11/2/201715
Kate11/1/201714
John11/3/201718
Kate11/2/201720
Jim11/1/201725
Kate11/3/201730
Kate11/4/201740
Jim11/1/201720
John11/4/201760

<tbody>
</tbody>

Sheet2 (processing)

name2nd occurrence value
John18
Kate30
Jim25

<colgroup><col><col></colgroup><tbody>
</tbody>


In B2 of Sheet2 control+shift+enter, not just enter, and copy down:

=INDEX(Sheet1!$C$1:$C$10,MAX(IF(Sheet1!$A$1:$A$10=$A2,IF(Sheet1!$B$1:$B$10=LARGE(IF(Sheet1!$A$1:$A$10=$A2,Sheet1!$B$1:$B$10),2),ROW(Sheet1!$C$1:$C$10)-ROW(Sheet1!$C$1)+1))))
 
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