Near Vlookup Help??

cameronb

Board Regular
Joined
Feb 13, 2009
Messages
146
I have two lists of data, both include lists of companies. I am looking for a formula which will return an 80% match, or closest mathc.

So for example:

Sheet 1
Column A
Britvic Ltd
Pepsi Co
BP Ltd
Coca Cola


Sheet 2
Column A Column B
Britvic Ltd "Formula"
Pepsi
BP
Coca Cola Ltd

Cell B1 above would Britvic Ltd and B2 would return Pepsi Co.

I have tried using Vlookup with False as match type and it will return a completely different cell. I have also combined INDEX with Match and got similar results.

I have 8,000 rows of data and before I start doing this manually using filters, does anyone have any suggestions?
 

Excel Facts

Show numbers in thousands?
Use a custom number format of #,##0,K. Each comma after the final 0 will divide the displayed number by another thousand
You'd need to use TRUE as your match type

FALSE looks for an exact match, TRUE (or omitted) looks for the nearest ;)
 
Upvote 0
Depending on what values you have in the two ranges you may be able to use a compund lookup to generate the results (quite probably won't generate all of them though) - in the following assume the ranges are on different sheets:

<b>Excel 2002</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 /></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></tr></thead><tbody><tr ><td style="color: #161120;text-align: center;">1</td><td style="font-weight: bold;;">Sheet 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="font-weight: bold;;">Sheet 2</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="font-weight: bold;;">Column A</td><td style="font-weight: bold;;">Lookup Formula</td><td style="font-weight: bold;text-align: right;;"></td><td style="font-weight: bold;text-align: right;;"></td><td style="font-weight: bold;text-align: right;;"></td><td style="font-weight: bold;;">Column A</td><td style="font-weight: bold;;">Lookup Formula</td><td style="font-weight: bold;;">Consolidator Formula</td></tr><tr ><td style="color: #161120;text-align: center;">3</td><td style=";">Britvic Ltd</td><td style=";">Britvic Ltd</td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style=";">Britvic Ltd</td><td style=";">Britvic Ltd</td><td style=";">Britvic Ltd</td></tr><tr ><td style="color: #161120;text-align: center;">4</td><td style=";">Pepsi Co</td><td style=";">Pepsi</td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style=";">Pepsi</td><td style="text-align: right;;">#N/A</td><td style=";">Pepsi Co</td></tr><tr ><td style="color: #161120;text-align: center;">5</td><td style=";">BP Ltd</td><td style=";">BP</td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style=";">BP</td><td style="text-align: right;;">#N/A</td><td style=";">BP Ltd</td></tr><tr ><td style="color: #161120;text-align: center;">6</td><td style=";">Coca Cola</td><td style="text-align: right;;">#N/A</td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style=";">Coca Cola Ltd</td><td style=";">Coca Cola</td><td style=";">Coca Cola</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">G3</th><td style="text-align:left">=LOOKUP(<font color="Blue">2^15,SEARCH(<font color="Red">$A$3:$A$6,F3</font>),$A$3:$A$6</font>)</td></tr><tr><th width="10px" style=" background-color: #E0E0F0;color: #161120">H3</th><td style="text-align:left">=IF(<font color="Blue">ISNA(<font color="Red">G3</font>),INDEX(<font color="Red">$A$3:$A$6,MATCH(<font color="Green">F3,$B$3:$B$6,0</font>)</font>),G3</font>)</td></tr><tr><th width="10px" style=" background-color: #E0E0F0;color: #161120">B3</th><td style="text-align:left">=LOOKUP(<font color="Blue">2^15,SEARCH(<font color="Red">$F$3:$F$6,A3</font>),$F$3:$F$6</font>)</td></tr></tbody></table></td></tr></table><br />
 
Upvote 0

Forum statistics

Threads
1,224,618
Messages
6,179,916
Members
452,949
Latest member
beartooth91

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