Hi Hilary,

Mind sharing your solution with the group?

What came to mind for me was an array solution that uses small/row to
identify the second smallest row number for the matching name, and index to
retrieve the reference to the cell.

 

Here's a formula using that approach:

{

=INDEX(NamesRange,SMALL(IF(NamesRange=NameToFind,ROW(NamesRange)),OccurenceN
umber)-ROW(INDEX(NamesRange,1))+1)

}

 

If you were going to use many of these formulas, NamesRange was large, and
often there was not going to be a match (for example there was only one
occurrence and you were looking for the second), you could speed up the
formulas by use the following version that checks the count (using countif)
of matching names, and if the count is < OccurenceNumber (2 in your stated
question) it will skip the array formula and just return an error.  If there
will usually be a match, this would actually be slower since it has the
added countif.

{

=IF(COUNTIF(NamesRange,NameToFind)<OccurenceNumber,#NUM!,INDEX(NamesRange,SM
ALL(IF(NamesRange=NameToFind,ROW(NamesRange)),OccurenceNumber)-ROW(INDEX(Nam
esRange,1))+1))

}

 

 

Upon a little more thought, here is a non-array solution for finding exactly
the 2nd occurrence (the array version would work for finding any specific
occurrence).  It uses match to find the first occurrence, then another match
to find the next occurrence. It should be faster---it has less work to do.
If there is no match it either returns an NA error or if the only match was
on the very last row of the range, a REF error.

=INDEX(NamesRange,MATCH(NameToFind,NamesRange,0)+MATCH(NameToFind,INDEX(Name
sRange,MATCH(NameToFind,NamesRange,0)+1):INDEX(NamesRange,ROWS(NamesRange)),
0))

 

Asa

 

-----Original Message-----
From: excel-macros@googlegroups.com [mailto:excel-macros@googlegroups.com]
On Behalf Of resp...@gmail.com
Sent: Thursday, May 31, 2012 2:01 PM
To: excel-macros@googlegroups.com
Subject: Re: $$Excel-Macros$$ Lookup and return 2nd occurrance

 

Thanks guys I have figured it out with index and match and countif. Thanks

Sent from my BlackBerryR smartphone from Airtel Ghana

 

-----Original Message-----

From:  <mailto:resp...@gmail.com> resp...@gmail.com

Sender:  <mailto:excel-macros@googlegroups.com>
excel-macros@googlegroups.com

Date: Thu, 31 May 2012 19:42:32 

To: < <mailto:excel-macros@googlegroups.com> excel-macros@googlegroups.com>

Reply-To:  <mailto:excel-macros@googlegroups.com>
excel-macros@googlegroups.com

Subject: $$Excel-Macros$$ Lookup and return 2nd occurrance

 

Hello Excel Masters

 

if I have a list if names like below in column A and say I have
corresponding different figures in column B.  

Hilary

Rajan

Maries

Noorain

Hilary

Rajan

Don

Kris

Asa

 

And so on and I want to return for instance the second occurance of hilary
with its corresponding figure. Kindly help with formula. Thanks. 

Sent from my BlackBerryR smartphone from Airtel Ghana

 

-- 

FORUM RULES (986+ members already BANNED for violation)

 

1) Use concise, accurate thread titles. Poor thread titles, like Please
Help, Urgent, Need Help, Formula Problem, Code Problem, and Need Advice will
not get quick attention or may not be answered.

 

2) Don't post a question in the thread of another member.

 

3) Don't post questions regarding breaking or bypassing any security
measure.

 

4) Acknowledge the responses you receive, good or bad.

 

5)  Cross-promotion of, or links to, forums competitive to this forum in
signatures are prohibited. 

 

NOTE  : Don't ever post personal or confidential data in a workbook. Forum
owners and members are not responsible for any loss.

 

----------------------------------------------------------------------------
--------------------------

To post to this group, send email to  <mailto:excel-macros@googlegroups.com>
excel-macros@googlegroups.com

 

To unsubscribe, send a blank email to
<mailto:excel-macros+unsubscr...@googlegroups.com>
excel-macros+unsubscr...@googlegroups.com

 

-- 

FORUM RULES (986+ members already BANNED for violation)

 

1) Use concise, accurate thread titles. Poor thread titles, like Please
Help, Urgent, Need Help, Formula Problem, Code Problem, and Need Advice will
not get quick attention or may not be answered.

 

2) Don't post a question in the thread of another member.

 

3) Don't post questions regarding breaking or bypassing any security
measure.

 

4) Acknowledge the responses you receive, good or bad.

 

5)  Cross-promotion of, or links to, forums competitive to this forum in
signatures are prohibited. 

 

NOTE  : Don't ever post personal or confidential data in a workbook. Forum
owners and members are not responsible for any loss.

 

----------------------------------------------------------------------------
--------------------------

To post to this group, send email to  <mailto:excel-macros@googlegroups.com>
excel-macros@googlegroups.com

 

To unsubscribe, send a blank email to
<mailto:excel-macros+unsubscr...@googlegroups.com>
excel-macros+unsubscr...@googlegroups.com

-- 
FORUM RULES (986+ members already BANNED for violation)

1) Use concise, accurate thread titles. Poor thread titles, like Please Help, 
Urgent, Need Help, Formula Problem, Code Problem, and Need Advice will not get 
quick attention or may not be answered.

2) Don't post a question in the thread of another member.

3) Don't post questions regarding breaking or bypassing any security measure.

4) Acknowledge the responses you receive, good or bad.

5)  Cross-promotion of, or links to, forums competitive to this forum in 
signatures are prohibited. 

NOTE  : Don't ever post personal or confidential data in a workbook. Forum 
owners and members are not responsible for any loss.

------------------------------------------------------------------------------------------------------
To post to this group, send email to excel-macros@googlegroups.com

To unsubscribe, send a blank email to excel-macros+unsubscr...@googlegroups.com

Reply via email to