Trouble removing formatting in vlookup area

MSC

Board Regular
Joined
Sep 23, 2004
Messages
63
Office Version
  1. 365
  2. 2021
Platform
  1. Windows
  2. MacOS
Hi, I've used vlookups for many years but recently inherited a project involving a 3rd party data source, and a vlookup problem I'm not able to solve.

This spreadsheet has about 50 product names in column A, and corresponding data in columns B, C, D, etc., straight across in rows.
To the naked eye, the formatting doesn't appear to be odd, but it's strange alright: when I setup the vlookup in the destination tab, -most- of the formulas work, but not all.

After searching every which way to strip out funky formatting from the names in column A (=trim, text, paste into notepad, paste values, etc.), the only way I can get the problematic vlookups to work is to manually type over the product name. Sometimes the product name is 2 words, sometimes it's just 2, and hitting F2 reveals there are no stray spaces on the front or back.

What else could I do to help solve this without retyping every name? Thank you, love this forum....
 
What else could I do to help solve this without retyping every name?
If it would be easier to not bother actually changing that 3rd party data, you could just change your VLOOKUP formula to something like this.
In my example I am looking up the value in F2 in the dodgy data column A and returning the value from column B
Excel Formula:
=INDEX(B$2:B$50,MATCH(F2,TRIM(SUBSTITUTE(A$2:A$50,UNICHAR(8203),"")),0))

Of course if column B might also have the '8203' character and/or trailing space then you may want to clean up the result as well.
This formula assumes the values in column B are (possibly dodgy) text values, but if they are numerical or could be some of each then the formula could be adapted.
Excel Formula:
=TRIM(SUBSTITUTE(INDEX(B$2:B$50,MATCH(F2,TRIM(SUBSTITUTE(A$2:A$50,UNICHAR(8203),"")),0)),UNICHAR(8203),""))
 
Upvote 0

Excel Facts

What is the fastest way to copy a formula?
If A2:A50000 contain data. Enter a formula in B2. Select B2. Double-click the Fill Handle and Excel will shoot the formula down to B50000.
If it would be easier to not bother actually changing that 3rd party data
Easier than doing a one line replace code (post 10)? Personally I'd rather clean the data and have a formula with less functions
 
Upvote 0
Easier than doing a one line replace code (post 10)?
Could be, depends a bit on whether the process has to be repeated in the future.
  • Mightn't have or want to have or be able to have a macro-enabled file, or policy might have macros disabled.
  • Copy/paste 1 formula & double-click Fill handle easier than open vba editor, insert module, copy/paste vba code, steps to run the code, (possibly) Save As macro-enabled
In any case, just offering options. :)
 
Upvote 0
Thank you for all this info, I've copy/pasted some of these tips into a sheet I maintain.
Now that I've fixed what ailed those names, for future iterations of this report I'm just going to copy/paste the new set of names that actually works, right over the problematic set that gets generated each time. Thanks again for everyone's help.
 
Upvote 0
Cheers. Glad you have something that you can work with. Thanks for letting us know. (y)
 
Upvote 0

Forum statistics

Threads
1,224,815
Messages
6,181,136
Members
453,021
Latest member
Justyna P

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