returning the 2nd instance...

kazbear

New Member
Joined
Dec 16, 2002
Messages
38
I am using this formula to match results (It works great):
=INDEX('sheet'!$A$2:$J$1293,MATCH(1,('Sheet'!$A$2:$A$1293=$E$8)*('Sheet'!$E$2:$E$1293=A29)*('sheet'!$G$2:$G$1293<>"Delete Item")*('sheet'!$G$2:$G$1293<>"Locked Item"),0),10)

Most of the time there will be only one result. But I do have a couple of instances where there will be more than one result. I would like to return those values as well.

The cell value I am capturing is text.

Is there a way I can modify this formula to return the second (or third, etc...) match?
 

Some videos you may like

Excel Facts

Fastest way to copy a worksheet?
Hold down the Ctrl key while dragging tab for Sheet1 to the right. Excel will make a copy of the worksheet.

LloydFinancials

Well-known Member
Joined
Apr 24, 2015
Messages
518
Hi Kazbear,

I propose the following. Let me know if you have any questions.

<b>Excel 2010</b><table cellpadding="2.5px" rules="all" style=";background-color: #FFFFFF;border: 1px solid;border-collapse: collapse; border-color: #BBB"><colgroup><col width="25px" style="background-color: #DAE7F5" /><col /><col /><col /><col /><col /><col /></colgroup><thead><tr style=" background-color: #DAE7F5;text-align: center;color: #161120"><th></th><th>A</th><th>E</th><th>G</th><th>J</th><th>M</th><th>N</th></tr></thead><tbody><tr ><td style="color: #161120;text-align: center;">1</td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style=";">c</td></tr><tr ><td style="color: #161120;text-align: center;">2</td><td style="text-align: right;;">5</td><td style="text-align: right;;">6</td><td style="text-align: right;;">Delete Item</td><td style="text-align: right;;">a</td><td style="text-align: right;;"></td><td style=";">f</td></tr><tr ><td style="color: #161120;text-align: center;">3</td><td style="text-align: right;;">5</td><td style="text-align: right;;">6</td><td style="text-align: right;;">Locked Item</td><td style="text-align: right;;">b</td><td style="text-align: right;;"></td><td style="text-align: right;;">#NUM!</td></tr><tr ><td style="color: #161120;text-align: center;">4</td><td style="text-align: right;;">5</td><td style="text-align: right;;">6</td><td style="text-align: right;;">x</td><td style="text-align: right;;">c</td><td style="text-align: right;;"></td><td style="text-align: right;;"></td></tr><tr ><td style="color: #161120;text-align: center;">5</td><td style="text-align: right;;">4</td><td style="text-align: right;;">6</td><td style="text-align: right;;"></td><td style="text-align: right;;">d</td><td style="text-align: right;;"></td><td style="text-align: right;;"></td></tr><tr ><td style="color: #161120;text-align: center;">6</td><td style="text-align: right;;">5</td><td style="text-align: right;;">3</td><td style="text-align: right;;"></td><td style="text-align: right;;">e</td><td style="text-align: right;;"></td><td style="text-align: right;;"></td></tr><tr ><td style="color: #161120;text-align: center;">7</td><td style="text-align: right;;">5</td><td style="text-align: right;;">6</td><td style="text-align: right;;"></td><td style="text-align: right;;">f</td><td style="text-align: right;;"></td><td style="text-align: right;;"></td></tr><tr ><td style="color: #161120;text-align: center;">8</td><td style="text-align: right;;"></td><td style="text-align: right;;">5</td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td></tr><tr ><td style="color: #161120;text-align: center;">9</td><td style="text-align: right;;"></td><td style="text-align: right;;">.</td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td></tr><tr ><td style="color: #161120;text-align: center;">29</td><td style="text-align: right;;">6</td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td></tr></tbody></table><p style="width:3em;font-weight:bold;margin:0;padding:0.2em 0.6em 0.2em 0.5em;border: 1px solid #BBB;border-top:none;text-align: center;background-color: #DAE7F5;color: #161120">Sheet</p><br /><br /><table width="85%" cellpadding="2.5px" rules="all" style=";border: 2px solid black;border-collapse:collapse;padding: 0.4em;background-color: #FFFFFF" ><tr><td style="padding:6px" ><b>Array Formulas</b><table cellpadding="2.5px" width="100%" rules="all" style="border: 1px solid;text-align:center;background-color: #FFFFFF;border-collapse: collapse; border-color: #BBB"><thead><tr style=" background-color: #DAE7F5;color: #161120"><th width="10px">Cell</th><th style="text-align:left;padding-left:5px;">Formula</th></tr></thead><tbody><tr><th width="10px" style=" background-color: #DAE7F5;color: #161120">N1</th><td style="text-align:left">{=INDEX(<font color="Blue">$A$2:$J$1293,SMALL(<font color="Red">IF(<font color="Green">(<font color="Purple">Sheet!$A$2:$A$1293=$E$8</font>)*(<font color="Purple">Sheet!$E$2:$E$1293=$A$29</font>)*(<font color="Purple">$G$2:$G$1293<>"Delete Item"</font>)*(<font color="Purple">$G$2:$G$1293<>"Locked Item"</font>),ROW(<font color="Purple">$A$2:$A$1293</font>)-MIN(<font color="Purple">ROW(<font color="Teal">$A$2:$A$1293</font>)</font>)+1,""</font>),ROWS(<font color="Green">1:$1</font>)</font>),10</font>)}</td></tr></tbody></table><b>Entered with Ctrl+Shift+Enter.</b> If entered correctly, Excel will surround with curly braces {}.
<b>Note: Do not try and enter the {} manually yourself</b></td></tr></table><br />

'Great day,

Luke
 

kazbear

New Member
Joined
Dec 16, 2002
Messages
38
Works perfect.
Thank you. I should be able to use this same concept now for the other areas where I have similar needs...
 

Watch MrExcel Video

Forum statistics

Threads
1,127,505
Messages
5,625,205
Members
416,080
Latest member
blemon

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
Top