Rows, Index, Small with wildcard!

Akashwani

Well-known Member
Joined
Mar 14, 2009
Messages
2,911
Hi,

Is it possible to add some wild card structure to the formulas in G4:J4 so that it can look within a text string for a word and return all the relevant data?

Please see below....

Excel Workbook
ABCDEFGHIJ
1NameAnimalColourSize******
2AlanWild DogBlack1*4*Table 1**
3BillPet DogBlue2*DogNameAnimalColourSize
4BobHot DogWhite3**FredDogWhite7
5CarlCool CatRed4******
6DaveBig CatGreen5******
7EricWild CatBlack6*4*Table2**
8FredDogWhite7*DogNameAnimalColourSize
9GinaCatRed8**AlanWild DogBlack1
10******BillPet DogBlue2
11******BobHot DogWhite3
12******FredDogWhite7
Test



The end result with a modified formula should be the same as Table2.

Is this possible am I going about this the wrong way?

Thanks

Ak
 

Excel Facts

Format cells as currency
Select range and press Ctrl+Shift+4 to format cells as currency. (Shift 4 is the $ sign).
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.
 
Upvote 0
Hi Haseeb,

Thank you very, very much for your (Aladin's) solution, it's perfect.
I don't think that I was almost there though :)

Thanks again, you have saved my sanity.

Ak
 
Upvote 0

Forum statistics

Threads
1,224,602
Messages
6,179,845
Members
452,948
Latest member
UsmanAli786

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