Vlookup to get multiple occurances

Dodger2

New Member
Joined
Feb 9, 2007
Messages
5
I currently have an Excel sheet in Excel 2007 that needs a summary report. I would normally do a simple VLOOKUP from column A. However, I need to find various occurances of the same string and do a lookup of it. Is there a way of getting the first and second occurance of a text string and getting a lookup into colmns B, C etc. Is there a way of combining the VLOOKUP with an offset to get the result as a VLOOKUP will only find the first occurance...thanks
 

Excel Facts

Save Often
If you start asking yourself if now is a good time to save your Excel workbook, the answer is Yes
You can use Match to give you the row in which the first occurance happens, and then OFFSET or INDEX to start your second lookup from that point.
 
Upvote 0
My apologies for not responding earlier....this is exactly what I was looking for - had to spend a few minutes getting to know how to use the Index function and it is one of those that I am sure will be useful in the future.
Again - many thanks for help and the quick response
 
Upvote 0
Try,

<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 /></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></tr></thead><tbody><tr ><td style="color: #161120;text-align: center;">1</td><td style="font-weight: bold;;">Filed1</td><td style="font-weight: bold;;">Filed2</td><td style="font-weight: bold;;">Amount</td><td style="text-align: right;;"></td><td style="font-weight: bold;;">Lookup Value</td><td style="text-align: right;;"></td><td style="font-weight: bold;;">Filed1</td><td style="font-weight: bold;;">Filed2</td><td style="font-weight: bold;;">Amount</td></tr><tr ><td style="color: #161120;text-align: center;">2</td><td style=";">A</td><td style=";">ASD</td><td style="text-align: right;;">100</td><td style="text-align: right;;"></td><td style="text-align: center;;">A</td><td style="text-align: right;;"></td><td style=";">A</td><td style=";">ASD</td><td style="text-align: right;;">100</td></tr><tr ><td style="color: #161120;text-align: center;">3</td><td style=";">B</td><td style=";">SDF</td><td style="text-align: right;;">365</td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style=";">A</td><td style=";">FGH</td><td style="text-align: right;;">241</td></tr><tr ><td style="color: #161120;text-align: center;">4</td><td style=";">C</td><td style=";">DFG</td><td style="text-align: right;;">514</td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style=";">A</td><td style=";">HJK</td><td style="text-align: right;;">541</td></tr><tr ><td style="color: #161120;text-align: center;">5</td><td style=";">A</td><td style=";">FGH</td><td style="text-align: right;;">241</td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style=";"></td><td style=";"></td><td style=";"></td></tr><tr ><td style="color: #161120;text-align: center;">6</td><td style=";">C</td><td style=";">GHJ</td><td style="text-align: right;;">365</td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style=";"></td><td style=";"></td><td style=";"></td></tr><tr ><td style="color: #161120;text-align: center;">7</td><td style=";">A</td><td style=";">HJK</td><td style="text-align: right;;">541</td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style=";"></td><td style=";"></td><td style=";"></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">Sheet1</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">G2</th><td style="text-align:left">=IF(<font color="Blue">H2="","",$E$2</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">H2</th><td style="text-align:left">{=IFERROR(<font color="Blue">INDEX(<font color="Red">B$2:B$7,SMALL(<font color="Green">IF(<font color="Purple">$A$2:$A$7=$E$2,ROW(<font color="Teal">$A$2:$A$7</font>)-ROW(<font color="Teal">$A$2</font>)+1</font>),ROWS(<font color="Purple">H$2:H2</font>)</font>)</font>),""</font>)}</td></tr><tr><th width="10px" style=" background-color: #E0E0F0;color: #161120">I2</th><td style="text-align:left">{=IFERROR(<font color="Blue">INDEX(<font color="Red">C$2:C$7,SMALL(<font color="Green">IF(<font color="Purple">$A$2:$A$7=$E$2,ROW(<font color="Teal">$A$2:$A$7</font>)-ROW(<font color="Teal">$A$2</font>)+1</font>),ROWS(<font color="Purple">I$2:I2</font>)</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 />
Copy down...
 
Upvote 0

Forum statistics

Threads
1,214,943
Messages
6,122,380
Members
449,080
Latest member
Armadillos

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