varying ranges for vlookup

bp

New Member
Joined
May 7, 2002
Messages
4
How can I create a vlookup statement with the range as a variable? In other words, I need the "range_array" portion of the statement to change according to certain conditions.
 

Excel Facts

How to change case of text in Excel?
Use =UPPER() for upper case, =LOWER() for lower case, and =PROPER() for proper case. PROPER won't capitalize second c in Mccartney
I have named multiple named ranges for different years. Therefore, if I have a date given in 2001 elsewhere in the worksheet, I need the vlookup to look at the "2001 range".
 
Upvote 0
bp,

if there's a logical sequence to your multiple named ranges, this shouldn't be a problem......

I set up some called :

yr2000
yr2001
yr2002
yr2003

etc

this allowed me to VLOOKUP on a cell (say containing the word "Sammi" then in the range array I was able to interrogate the date that was sitting on "Sammi"s row

(say 13 May 2002)

as follows :

=YEAR(A1)

which brought back "2002"

since that corrosponds with the logic of my named ranges, I popped it into an indirect as part of the range array as follows :

=VLOOKUP(A1,INDIRECT("yr"&YEAR(B1)),1,0)

where A1 held "Sammi"
where B1 held "13/05/2002"
and the named range of year 2002 was "yr2002"
 
Upvote 0
Chris,

That did exactly what I needed!

Thank you very much for your assistance!
 
Upvote 0

Forum statistics

Threads
1,213,528
Messages
6,114,154
Members
448,553
Latest member
slaytonpa

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