find first specific text string

Excel Facts

What do {} around a formula in the formula bar mean?
{Formula} means the formula was entered using Ctrl+Shift+Enter signifying an old-style array formula.
If you want to actually start this from row 2 downward, in D2:
=IFERROR(LOOKUP(2,1/($A$1:A1=A2),$B$1:B1),"")
Copy down.

Otherwise, the formula in D9 specifically is:
=IFERROR(LOOKUP(2,1/($A$1:A8=A9),$B$1:B8),"")

<b>Sheet1</b><br /><br /><table border="1" cellspacing="0" cellpadding="0" style="font-family:Calibri,Arial; font-size:11pt; background-color:#ffffff; padding-left:2pt; padding-right:2pt; "> <colgroup><col style="font-weight:bold; width:30px; " /><col style="width:64px;" /><col style="width:64px;" /><col style="width:64px;" /><col style="width:64px;" /></colgroup><tr style="background-color:#cacaca; text-align:center; font-weight:bold; font-size:8pt; "><td > </td><td >A</td><td >B</td><td >C</td><td >D</td></tr><tr style="height:18px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >1</td><td >larry</td><td style="text-align:right; ">3</td><td >a</td><td > </td></tr><tr style="height:18px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >2</td><td >john</td><td style="text-align:right; ">10</td><td >c</td><td > </td></tr><tr style="height:18px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >3</td><td >mary</td><td style="text-align:right; ">4</td><td >b</td><td > </td></tr><tr style="height:18px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >4</td><td >steve</td><td style="text-align:right; ">5</td><td >b</td><td > </td></tr><tr style="height:18px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >5</td><td >larry</td><td style="text-align:right; ">8</td><td >c</td><td style="text-align:right; ">3</td></tr><tr style="height:18px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >6</td><td >peter</td><td style="text-align:right; ">6</td><td >a</td><td > </td></tr><tr style="height:18px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >7</td><td >steve</td><td style="text-align:right; ">7</td><td >a</td><td style="text-align:right; ">5</td></tr><tr style="height:18px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >8</td><td >mike</td><td style="text-align:right; ">8</td><td >a</td><td > </td></tr><tr style="height:18px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >9</td><td >larry</td><td style="text-align:right; ">3</td><td >a</td><td style="text-align:right; ">8</td></tr></table><br /><table style="font-family:Arial; font-size:10pt; border-style: groove ;border-color:#00ff00;background-color:#fffcf9; color:#000000; "><tr><td ><b>Spreadsheet Formulas</b></td></tr><tr><td ><table border = "1" cellspacing="0" cellpadding="2" style="font-family:Arial; font-size:9pt;"><tr style="background-color:#cacaca; font-size:10pt;"><td >Cell</td><td >Formula</td></tr><tr><td >D2</td><td >=IFERROR(LOOKUP<span style=' color:008000; '>(2,1/<span style=' color:#0000ff; '>($A$1:A1=A2)</span>,$B$1:B1)</span>,"")</td></tr><tr><td >D3</td><td >=IFERROR(LOOKUP<span style=' color:008000; '>(2,1/<span style=' color:#0000ff; '>($A$1:A2=A3)</span>,$B$1:B2)</span>,"")</td></tr><tr><td >D4</td><td >=IFERROR(LOOKUP<span style=' color:008000; '>(2,1/<span style=' color:#0000ff; '>($A$1:A3=A4)</span>,$B$1:B3)</span>,"")</td></tr><tr><td >D5</td><td >=IFERROR(LOOKUP<span style=' color:008000; '>(2,1/<span style=' color:#0000ff; '>($A$1:A4=A5)</span>,$B$1:B4)</span>,"")</td></tr><tr><td >D6</td><td >=IFERROR(LOOKUP<span style=' color:008000; '>(2,1/<span style=' color:#0000ff; '>($A$1:A5=A6)</span>,$B$1:B5)</span>,"")</td></tr><tr><td >D7</td><td >=IFERROR(LOOKUP<span style=' color:008000; '>(2,1/<span style=' color:#0000ff; '>($A$1:A6=A7)</span>,$B$1:B6)</span>,"")</td></tr><tr><td >D8</td><td >=IFERROR(LOOKUP<span style=' color:008000; '>(2,1/<span style=' color:#0000ff; '>($A$1:A7=A8)</span>,$B$1:B7)</span>,"")</td></tr><tr><td >D9</td><td >=IFERROR(LOOKUP<span style=' color:008000; '>(2,1/<span style=' color:#0000ff; '>($A$1:A8=A9)</span>,$B$1:B8)</span>,"")</td></tr></table></td></tr></table> <br /><br /><span style="font-family:Arial; font-size:9pt; font-weight:bold;background-color:#ffffff; color:#000000; ">Excel tables to the web >> </span>
 
Upvote 0
This could also be modified to show only the last result that had a match above it:

In that case in D2:
=IFERROR(LOOKUP(2,1/(($A$1:A1=A2)*COUNTIF($A$1:A2,A2)=COUNTIF(A:A,A2)),$B$1:B1),"")

Copy down.

<b>Sheet1</b><br /><br /><table border="1" cellspacing="0" cellpadding="0" style="font-family:Calibri,Arial; font-size:11pt; background-color:#ffffff; padding-left:2pt; padding-right:2pt; "> <colgroup><col style="font-weight:bold; width:30px; " /><col style="width:64px;" /><col style="width:64px;" /><col style="width:64px;" /><col style="width:64px;" /></colgroup><tr style="background-color:#cacaca; text-align:center; font-weight:bold; font-size:8pt; "><td > </td><td >A</td><td >B</td><td >C</td><td >D</td></tr><tr style="height:18px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >1</td><td >larry</td><td style="text-align:right; ">3</td><td >a</td><td > </td></tr><tr style="height:18px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >2</td><td >john</td><td style="text-align:right; ">10</td><td >c</td><td > </td></tr><tr style="height:18px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >3</td><td >mary</td><td style="text-align:right; ">4</td><td >b</td><td > </td></tr><tr style="height:18px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >4</td><td >steve</td><td style="text-align:right; ">5</td><td >b</td><td > </td></tr><tr style="height:18px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >5</td><td >larry</td><td style="text-align:right; ">8</td><td >c</td><td > </td></tr><tr style="height:18px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >6</td><td >peter</td><td style="text-align:right; ">6</td><td >a</td><td > </td></tr><tr style="height:18px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >7</td><td >steve</td><td style="text-align:right; ">7</td><td >a</td><td style="text-align:right; ">5</td></tr><tr style="height:18px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >8</td><td >mike</td><td style="text-align:right; ">8</td><td >a</td><td > </td></tr><tr style="height:18px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >9</td><td >larry</td><td style="text-align:right; ">3</td><td >a</td><td style="text-align:right; ">8</td></tr></table><br /><table style="font-family:Arial; font-size:10pt; border-style: groove ;border-color:#00ff00;background-color:#fffcf9; color:#000000; "><tr><td ><b>Spreadsheet Formulas</b></td></tr><tr><td ><table border = "1" cellspacing="0" cellpadding="2" style="font-family:Arial; font-size:9pt;"><tr style="background-color:#cacaca; font-size:10pt;"><td >Cell</td><td >Formula</td></tr><tr><td >D2</td><td >=IFERROR(LOOKUP<span style=' color:008000; '>(2,1/<span style=' color:#0000ff; '>(<span style=' color:#ff0000; '>($A$1:A1=A2)</span>*COUNTIF<span style=' color:#ff0000; '>($A$1:A2,A2)</span>=COUNTIF<span style=' color:#ff0000; '>(A:A,A2)</span>)</span>,$B$1:B1)</span>,"")</td></tr><tr><td >D3</td><td >=IFERROR(LOOKUP<span style=' color:008000; '>(2,1/<span style=' color:#0000ff; '>(<span style=' color:#ff0000; '>($A$1:A2=A3)</span>*COUNTIF<span style=' color:#ff0000; '>($A$1:A3,A3)</span>=COUNTIF<span style=' color:#ff0000; '>(A:A,A3)</span>)</span>,$B$1:B2)</span>,"")</td></tr><tr><td >D4</td><td >=IFERROR(LOOKUP<span style=' color:008000; '>(2,1/<span style=' color:#0000ff; '>(<span style=' color:#ff0000; '>($A$1:A3=A4)</span>*COUNTIF<span style=' color:#ff0000; '>($A$1:A4,A4)</span>=COUNTIF<span style=' color:#ff0000; '>(A:A,A4)</span>)</span>,$B$1:B3)</span>,"")</td></tr><tr><td >D5</td><td >=IFERROR(LOOKUP<span style=' color:008000; '>(2,1/<span style=' color:#0000ff; '>(<span style=' color:#ff0000; '>($A$1:A4=A5)</span>*COUNTIF<span style=' color:#ff0000; '>($A$1:A5,A5)</span>=COUNTIF<span style=' color:#ff0000; '>(A:A,A5)</span>)</span>,$B$1:B4)</span>,"")</td></tr><tr><td >D6</td><td >=IFERROR(LOOKUP<span style=' color:008000; '>(2,1/<span style=' color:#0000ff; '>(<span style=' color:#ff0000; '>($A$1:A5=A6)</span>*COUNTIF<span style=' color:#ff0000; '>($A$1:A6,A6)</span>=COUNTIF<span style=' color:#ff0000; '>(A:A,A6)</span>)</span>,$B$1:B5)</span>,"")</td></tr><tr><td >D7</td><td >=IFERROR(LOOKUP<span style=' color:008000; '>(2,1/<span style=' color:#0000ff; '>(<span style=' color:#ff0000; '>($A$1:A6=A7)</span>*COUNTIF<span style=' color:#ff0000; '>($A$1:A7,A7)</span>=COUNTIF<span style=' color:#ff0000; '>(A:A,A7)</span>)</span>,$B$1:B6)</span>,"")</td></tr><tr><td >D8</td><td >=IFERROR(LOOKUP<span style=' color:008000; '>(2,1/<span style=' color:#0000ff; '>(<span style=' color:#ff0000; '>($A$1:A7=A8)</span>*COUNTIF<span style=' color:#ff0000; '>($A$1:A8,A8)</span>=COUNTIF<span style=' color:#ff0000; '>(A:A,A8)</span>)</span>,$B$1:B7)</span>,"")</td></tr><tr><td >D9</td><td >=IFERROR(LOOKUP<span style=' color:008000; '>(2,1/<span style=' color:#0000ff; '>(<span style=' color:#ff0000; '>($A$1:A8=A9)</span>*COUNTIF<span style=' color:#ff0000; '>($A$1:A9,A9)</span>=COUNTIF<span style=' color:#ff0000; '>(A:A,A9)</span>)</span>,$B$1:B8)</span>,"")</td></tr></table></td></tr></table> <br /><br /><span style="font-family:Arial; font-size:9pt; font-weight:bold;background-color:#ffffff; color:#000000; ">Excel tables to the web >> </span>
 
Upvote 0
thanks a lot!

one more question,

what if I want in e9 and f9 cells instead of the first cell above,

look up for the second (e9) and the third (f9)
 
Upvote 0
Isn't that a lot like my first example where it showed all of them?
 
Upvote 0
in my case (first example)

I want e9 cell to show me the value 3

(bypass the value 8)
 
Last edited:
Upvote 0
In D9:

=IFERROR(INDEX($B:$B,LARGE(IF($A$1:$A8=$A9,ROW($A$1:$A8)),COLUMN(A1))),"")

Confirm with CTRL-SHIFT-ENTER rather than just Enter.
Copy across.

<b>Sheet1</b><br /><br /><table border="1" cellspacing="0" cellpadding="0" style="font-family:Calibri,Arial; font-size:11pt; background-color:#ffffff; padding-left:2pt; padding-right:2pt; "> <colgroup><col style="font-weight:bold; width:30px; " /><col style="width:64px;" /><col style="width:64px;" /><col style="width:64px;" /><col style="width:64px;" /><col style="width:64px;" /><col style="width:64px;" /></colgroup><tr style="background-color:#cacaca; text-align:center; font-weight:bold; font-size:8pt; "><td > </td><td >A</td><td >B</td><td >C</td><td >D</td><td >E</td><td >F</td></tr><tr style="height:18px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >1</td><td >larry</td><td style="text-align:right; ">3</td><td >a</td><td > </td><td > </td><td > </td></tr><tr style="height:18px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >2</td><td >john</td><td style="text-align:right; ">10</td><td >c</td><td > </td><td > </td><td > </td></tr><tr style="height:18px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >3</td><td >mary</td><td style="text-align:right; ">4</td><td >b</td><td > </td><td > </td><td > </td></tr><tr style="height:18px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >4</td><td >steve</td><td style="text-align:right; ">5</td><td >b</td><td > </td><td > </td><td > </td></tr><tr style="height:18px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >5</td><td >larry</td><td style="text-align:right; ">8</td><td >c</td><td > </td><td > </td><td > </td></tr><tr style="height:18px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >6</td><td >peter</td><td style="text-align:right; ">6</td><td >a</td><td > </td><td > </td><td > </td></tr><tr style="height:18px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >7</td><td >steve</td><td style="text-align:right; ">7</td><td >a</td><td > </td><td > </td><td > </td></tr><tr style="height:18px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >8</td><td >mike</td><td style="text-align:right; ">8</td><td >a</td><td > </td><td > </td><td > </td></tr><tr style="height:18px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >9</td><td >larry</td><td style="text-align:right; ">3</td><td >a</td><td style="text-align:right; ">8</td><td style="text-align:right; ">3</td><td > </td></tr></table><br /><table style="font-family:Arial; font-size:10pt; border-style: groove ;border-color:#00ff00;background-color:#fffcf9; color:#000000; "><tr><td ><b>Spreadsheet Formulas</b></td></tr><tr><td ><table border = "1" cellspacing="0" cellpadding="2" style="font-family:Arial; font-size:9pt;"><tr style="background-color:#cacaca; font-size:10pt;"><td >Cell</td><td >Formula</td></tr><tr><td >D9</td><td >{=IFERROR(INDEX<span style=' color:008000; '>($B:$B,LARGE<span style=' color:#0000ff; '>(IF<span style=' color:#ff0000; '>($A$1:$A8=$A9,ROW<span style=' color:#804000; '>($A$1:$A8)</span>)</span>,COLUMN<span style=' color:#ff0000; '>(A1)</span>)</span>)</span>,"")}</td></tr><tr><td >E9</td><td >{=IFERROR(INDEX<span style=' color:008000; '>($B:$B,LARGE<span style=' color:#0000ff; '>(IF<span style=' color:#ff0000; '>($A$1:$A8=$A9,ROW<span style=' color:#804000; '>($A$1:$A8)</span>)</span>,COLUMN<span style=' color:#ff0000; '>(B1)</span>)</span>)</span>,"")}</td></tr><tr><td >F9</td><td >{=IFERROR(INDEX<span style=' color:008000; '>($B:$B,LARGE<span style=' color:#0000ff; '>(IF<span style=' color:#ff0000; '>($A$1:$A8=$A9,ROW<span style=' color:#804000; '>($A$1:$A8)</span>)</span>,COLUMN<span style=' color:#ff0000; '>(C1)</span>)</span>)</span>,"")}</td></tr></table></td></tr><tr><td ><span style=' font-family:Arial,Arial; font-size:9pt; font-weight:bold;'>Formula Array:</span><span style=' font-family:Arial,Arial; font-size:9pt;'><br />Produce enclosing </span><span style=' font-family:Arial,Arial; font-size:9pt; font-weight:bold;'>{ }</span><span style=' font-family:Arial,Arial; font-size:9pt;'> by entering<br />formula with CTRL+SHIFT+ENTER!</span></td></tr></table> <br /><br /><span style="font-family:Arial; font-size:9pt; font-weight:bold;background-color:#ffffff; color:#000000; ">Excel tables to the web >> </span>
 
Upvote 0
=IFERROR(INDEX($C:$C,LARGE(IF($B$1:$B8=$B9,IF($A$1:$A8=$A9,ROW($B$1:$B8))),COLUMN(A1))),"")

Confirm with CTRL-SHIFT-ENTER. Copy across.
 
Upvote 0

Forum statistics

Threads
1,214,593
Messages
6,120,435
Members
448,962
Latest member
Fenes

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