looking up values w/o macros

steve_stiller

New Member
Joined
Sep 1, 2006
Messages
28
Hi,

I have two issues that involving looking up cells in a table... however, the catch is I can't use a macro but only functions built into excel.

First I need to lookup the second and third occurences of a value and return the adjacent cell. I usually, use a macro called nth_occurrence, but due to the updating of my spreadhseet, this has to be done using Match or other built-in functions. And that's where I get stumped. For example. a table A1:b5

1 bob
0 bill
0 bucky
1 steve
1 mike

I need to build a function that would pull the second corresponding occurrence of 1... meaning steve. I'm sure this may be rather simple, but I've been trying things and can't quite get it.

The other issue is, is there a way to return a corresponding row's cell to the highest value in a table w/o a macro.

1 bill
2 mark
5 bucky
4 steve
3 mary

the function would return "bucky". I'm clueless here and could greatly use the help.

Thank you,

Steve
 

Excel Facts

Does the VLOOKUP table have to be sorted?
No! when you are using an exact match, the VLOOKUP table can be in any order. Best-selling items at the top is actually the best.
1st formula


Code:
=INDEX(B:B,SMALL(IF(A1:A6=1,ROW(A1:A6)),2),1)

confirmed w/ ctrl + shift + enter


2nd formula


Code:
=INDEX(B:B,MATCH(MAX(A1:A6),A1:A6,0),1)

adjust to applicable ranges

HTH
 
Upvote 0
Hello there,

First question:

You could do a board search, which would wield you with some good results.

You could use...

=INDEX(A:B,MATCH(F1&CHAR(1)&F2,D:D,0),2)

This assumes data in column A and B with two helper columns, B and C. column B has a formula of ..

=COUNTIF($A$1:A1,A1)

Column C has a formula of ..

=A1&CHAR(1)&C1

Two variables used are in F1 (what number to find) and F2 (what numerical occurance it is). This also assumes no header row.



Second question:

=INDEX(A:B,MATCH(MAX(A:A),A:A,0),2)

This assumes data in in columns A and B, and data is not duplicated (in column A).



HTH
 
Upvote 0
Thanks so much guys. These work great.

One question though, for the second question about pulling max values out, what sort of adjustment would I need to make to the formula to take the second highest, third, etc. Goal here is to be able to make a top 5.

Thanks in advance,

Steve
 
Upvote 0
try this and drag down 5 rows:


Code:
=INDEX(B:B,MATCH(Large($A$1:$A$6,rows($1:1)),$A$1:$A$6,0),1)

HTH
 
Upvote 0

Forum statistics

Threads
1,213,479
Messages
6,113,897
Members
448,530
Latest member
yatong2008

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