Q: Named range based on cell value?

G

Guest

I want to do a vlookup based on a range that is based on a cell.

So, if cell A1 = "CA" use the CA_REG named range in my formula.
If cell A1 = "NV" use the NV_REG named range in my formula.
etc. etc.

There will be about a dozen values that the cell can have, so I can't use a
nested if.

Any ideas?
 
C

Chip Pearson

Try something like the following:

=VLOOKUP(xyz,INDIRECT(INDEX({"CA_REG","NV_REG","AB_REG"},0,MATCH(A1,{"CA","NV","AB"},0))),2,FALSE)

Change the 'xyz' to the value you want to look up with VLOOKUP.

--
Cordially,
Chip Pearson
Microsoft MVP - Excel, 10 Years
Pearson Software Consulting
www.cpearson.com
(email on the web site)
 
G

Guest

Thanks!!! Works great!

Chip Pearson said:
Try something like the following:

=VLOOKUP(xyz,INDIRECT(INDEX({"CA_REG","NV_REG","AB_REG"},0,MATCH(A1,{"CA","NV","AB"},0))),2,FALSE)

Change the 'xyz' to the value you want to look up with VLOOKUP.

--
Cordially,
Chip Pearson
Microsoft MVP - Excel, 10 Years
Pearson Software Consulting
www.cpearson.com
(email on the web site)
 
G

Guest

By the by, using your formula as a template, I think I found a bit of a
slimmer solution:

=VLOOKUP("xyz",CHOOSE(MATCH(A2,{"CA","NV"},0),CA_REG,NV_REG),2,FALSE)

So far, it seems to work. And again, thank you so much for your solution.

-Mark
 

Ask a Question

Want to reply to this thread or ask your own question?

You'll need to choose a username for the site, which only take a couple of moments. After that, you can post your question and our members will help you out.

Ask a Question

Top