Hello, You almost there, use the ISNUMBER(SEARCH(F3))
<b>Excel 2007</b><table cellpadding="2.5px" rules="all" style=";background-color: #FFFFFF;border: 1px solid;border-collapse: collapse; border-color: #A6AAB6"><colgroup><col width="25px" style="background-color: #E0E0F0" /><col /><col /><col /><col /><col /><col /><col /><col /><col /><col /></colgroup><thead><tr style=" background-color: #E0E0F0;text-align: center;color: #161120"><th></th><th>A</th><th>B</th><th>C</th><th>D</th><th>E</th><th>F</th><th>G</th><th>H</th><th>I</th><th>J</th></tr></thead><tbody><tr ><td style="color: #161120;text-align: center;">1</td><td style="font-weight: bold;text-align: center;;">Name</td><td style="font-weight: bold;text-align: center;;">Animal</td><td style="font-weight: bold;text-align: center;;">Colour</td><td style="font-weight: bold;text-align: center;;">Size</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;">2</td><td style=";">Alan</td><td style=";">Wild Dog</td><td style=";">Black</td><td style="text-align: right;;">1</td><td style="text-align: right;;"></td><td style="text-align: right;;">4</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;">3</td><td style=";">Bill</td><td style=";">Pet Dog</td><td style=";">Blue</td><td style="text-align: right;;">2</td><td style="text-align: right;;"></td><td style=";">Dog</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;">4</td><td style=";">Bob</td><td style=";">Hot Dog</td><td style=";">White</td><td style="text-align: right;;">3</td><td style="text-align: right;;"></td><td style=";">Row#</td><td style=";">Name</td><td style=";">Animal</td><td style=";">Colour</td><td style=";">Size</td></tr><tr ><td style="color: #161120;text-align: center;">5</td><td style=";">Carl</td><td style=";">Cool Cat</td><td style=";">Red</td><td style="text-align: right;;">4</td><td style="text-align: right;;"></td><td style="text-align: right;;">2</td><td style=";">Alan</td><td style=";">Wild Dog</td><td style=";">Black</td><td style="text-align: right;;">1</td></tr><tr ><td style="color: #161120;text-align: center;">6</td><td style=";">Dave</td><td style=";">Big Cat</td><td style=";">Green</td><td style="text-align: right;;">5</td><td style="text-align: right;;"></td><td style="text-align: right;;">3</td><td style=";">Bill</td><td style=";">Pet Dog</td><td style=";">Blue</td><td style="text-align: right;;">2</td></tr><tr ><td style="color: #161120;text-align: center;">7</td><td style=";">Eric</td><td style=";">Wild Cat</td><td style=";">Black</td><td style="text-align: right;;">6</td><td style="text-align: right;;"></td><td style="text-align: right;;">4</td><td style=";">Bob</td><td style=";">Hot Dog</td><td style=";">White</td><td style="text-align: right;;">3</td></tr><tr ><td style="color: #161120;text-align: center;">8</td><td style=";">Fred</td><td style=";">Dog</td><td style=";">White</td><td style="text-align: right;;">7</td><td style="text-align: right;;"></td><td style="text-align: right;;">8</td><td style=";">Fred</td><td style=";">Dog</td><td style=";">White</td><td style="text-align: right;;">7</td></tr><tr ><td style="color: #161120;text-align: center;">9</td><td style=";">Gina</td><td style=";">Cat</td><td style=";">Red</td><td style="text-align: right;;">8</td><td style="text-align: right;;"></td><td style=";"></td><td style=";"></td><td style=";"></td><td style=";"></td><td style=";"></td></tr><tr ><td style="color: #161120;text-align: center;">10</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><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:3.6em;font-weight:bold;margin:0;padding:0.2em 0.6em 0.2em 0.5em;border: 1px solid #A6AAB6;border-top:none;text-align: center;background-color: #E0E0F0;color: #161120">Sheet2</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>Worksheet 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: #A6AAB6"><thead><tr style=" background-color: #E0E0F0;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: #E0E0F0;color: #161120">F2</th><td style="text-align:left">=COUNTIF(<font color="Blue">B2:B9,"*"&F3&"*"</font>)</td></tr><tr><th width="10px" style=" background-color: #E0E0F0;color: #161120">G5</th><td style="text-align:left">=IF(<font color="Blue">N(<font color="Red">$F5</font>),INDEX(<font color="Red">A:A,$F5</font>),""</font>)</td></tr></tbody></table></td></tr></table><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: #A6AAB6"><thead><tr style=" background-color: #E0E0F0;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: #E0E0F0;color: #161120">F5</th><td style="text-align:left">{=IF(<font color="Blue">ROWS(<font color="Red">F$2:F2</font>)<=$F$2,SMALL(<font color="Red">IF(<font color="Green">ISNUMBER(<font color="Purple">SEARCH(<font color="Teal">$F$3,$B$2:$B$9</font>)</font>),ROW(<font color="Purple">$B$2:$B$9</font>)</font>),ROWS(<font color="Green">F$2:F2</font>)</font>),""</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 />
F5 Copy down..
G5 Copy down & across...
If you want to show multiple columns, this method will be faster.
A good lesson from Aladin. Thanks to him.