Advice on vlookup across text and numbers?

sing2trees1983

New Member
Joined
Feb 3, 2006
Messages
26
Hello everyone. I have a list of "numbers" which consists of three letters followed by six numbers. Batches will belong to different clients. E.g. ABC100000 to ABC110000 belongs to client A, ABC110001 to ABC120000 belongs to client B etc.
I would really like members of staff to enter a number and the vlookup function will show the client. Is it possible to do this without listing all the number range options individually?
Hope that makes sense and a huge thank you for your help in advance!
 

Excel Facts

Add Bullets to Range
Select range. Press Ctrl+1. On Number tab, choose Custom. Type Alt+7 then space then @ sign (using 7 on numeric keypad)
Maybe something like this?
[Table="width:, class:grid"][tr][td] [/td][td]
A​
[/td][td]
B​
[/td][td]
C​
[/td][td]
D​
[/td][td]
E​
[/td][/tr]
[tr][td]
2​
[/td][td]ABC100000[/td][td]
10​
[/td][td][/td][td]
100003​
[/td][td]
40​
[/td][/tr]

[tr][td]
3​
[/td][td]ABC100001[/td][td]
20​
[/td][td][/td][td][/td][td][/td][/tr]

[tr][td]
4​
[/td][td]ABC100002[/td][td]
30​
[/td][td][/td][td][/td][td][/td][/tr]

[tr][td]
5​
[/td][td]ABC100003[/td][td]
40​
[/td][td][/td][td][/td][td][/td][/tr]

[tr][td]
6​
[/td][td]ABC100004[/td][td]
50​
[/td][td][/td][td][/td][td][/td][/tr]

[tr][td]
7​
[/td][td]ABC100005[/td][td]
60​
[/td][td][/td][td][/td][td][/td][/tr]

[tr][td]
8​
[/td][td]ABC110001[/td][td]
70​
[/td][td][/td][td][/td][td][/td][/tr]

[tr][td]
9​
[/td][td]ABC110002[/td][td]
80​
[/td][td][/td][td][/td][td][/td][/tr]

[tr][td]
10​
[/td][td]ABC110003[/td][td]
90​
[/td][td][/td][td][/td][td][/td][/tr]

[tr][td]
11​
[/td][td]ABC110004[/td][td]
100​
[/td][td][/td][td][/td][td][/td][/tr]

[tr][td]
12​
[/td][td]ABC110005[/td][td]
110​
[/td][td][/td][td][/td][td][/td][/tr]
[/table]

E2=VLOOKUP("ABC"&D2,$A$2:$B$12,2,0)
 
Upvote 0
Thanks so much for that - but is there a way of doing it where I don't need to type out every single possible number combination?
E.g not having to type:
ABC100000
ABC100001
ABC100002
ABC100003
all the way to
ABC110005?

Basically something that says if the text/number is between ABC100000 and ABC110000 then it is client A etc. Plus the letters may change, so another client might be DEF100000
 
Upvote 0
If they will all always have the same 1st letters, then you can pretty much skip using them for this. I suggest you will make a small table with your ranges, but you only need the upper and lower value of each range...
[Table="width:, class:grid"][tr][td] [/td][td]
F​
[/td][td]
G​
[/td][td]
H​
[/td][td]
I​
[/td][/tr]
[tr][td]
2​
[/td][td]
100000​
[/td][td]
10​
[/td][td]
110011​
[/td][td]
20​
[/td][/tr]

[tr][td]
3​
[/td][td]
100005​
[/td][td]
10​
[/td][td][/td][td][/td][/tr]

[tr][td]
4​
[/td][td]
110000​
[/td][td]
20​
[/td][td][/td][td][/td][/tr]

[tr][td]
5​
[/td][td]
110005​
[/td][td]
20​
[/td][td][/td][td][/td][/tr]

[tr][td]
6​
[/td][td]
120000​
[/td][td]
30​
[/td][td][/td][td][/td][/tr]

[tr][td]
7​
[/td][td]
120005​
[/td][td]
30​
[/td][td][/td][td][/td][/tr]
[/table]

Then pretty much the same formula...
I2=VLOOKUP(H2,$F$2:$G$7,2,1)
note that I used 1 at the end instead of 0
 
Upvote 0

Forum statistics

Threads
1,224,827
Messages
6,181,194
Members
453,021
Latest member
pingpong7117

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