VLOOKUP using a range with reference in a cell

bailey537

Board Regular
Joined
Jun 30, 2008
Messages
65
I want to be able to change the range my vlookup equation looks at depending on a value found in a cell. I.e 2008 looks in the 2008 range, 2009 in the 2009 range. Or if it would be easier a double vlookup

my ranges look like the following

2007, 1 , 100
2007, 2 ,150
2007, 3 , 200
2007, 4 , 250
2008, 1 , 125
2008, 2, 130
2008, 3, 165
2008, 4, 190

at the moment 07 and 08 are different named ranges
 

Excel Facts

Difference between two dates
Secret function! Use =DATEDIF(A2,B2,"Y")&" years"&=DATEDIF(A2,B2,"YM")&" months"&=DATEDIF(A2,B2,"MD")&" days"
Hi there,

From the sounds of it you are using named ranges for your VLOokup. If so and you want to effectuate this, you would need to use the indirect function to pull at information. So if in Cells D1, you have your named range you want to look into and E1 your search value, your Vlookup would be =vlookup(E1,Indirect(D1),2, False).

Hope this helps
jc
 
Upvote 0
Hi

Do you mean something like
Excel Workbook
ABCDEFGH
1RangeLookup ValReturn ValRangeLookup ValReturn Val
22007110020072150
320072150
420073200
520074250
620081125
720082130
820083165
920084190
Sheet1
Excel 2003
Cell Formulas
RangeFormula
H2=VLOOKUP(G2,OFFSET(INDEX($A$2:$A$9,MATCH(F2,$A$2:$A$9,0)),0,1,COUNTIF($A$2:$A$9,F2),2),2,0)
 
Upvote 0
Following up on sandeep.warrier data set up:

Here is the data and formulas (formulas in green):
Excel Workbook
ABCDEFGH
1RangeLookup ValReturn ValJoinRangeLookup ValReturn Val
2200711002007120082130
32007215020072
42007320020073
52007425020074
62008112520081
72008213020082
82008316520083
92008419020084
Sheet1
Excel 2010

Here is the formula in cell D2 (copied down):

=A2&B2

Here is the formula in cell H2:

=INDEX(C2:C9,MATCH(F2&G2,D2:D9,0))
 
Upvote 0
If you don't mind using Ctrl + Shift + Enter to put the formula into the cell, try this:

Here is the data and formula (formula in green):
Excel Workbook
ABCDEFGH
1RangeLookup ValReturn ValRangeLookup ValReturn Val
22007110020071100
320072150
420073200
520074250
620081125
720082130
820083165
920084190
Sheet1 (2)
Excel 2010

Then in cell H2 enter this formula with Ctrl + Shift + Enter:

=INDEX(C2:C9,MATCH(F2&G2,A2:A9&B2:B9,0))
 
Upvote 0
Using Mike Gel Girvin's table

Herein a database function solution :

H2, formula (one of) :

=DSUM(A1:C9,H1,F1:G2)

=DSUM(A1:C9,3,F1:G2)

=DGET(A1:C9,H1,F1:G2)

=DGET(A1:C9,3,F1:G2)

Regards
 
Last edited:
Upvote 0

Forum statistics

Threads
1,214,430
Messages
6,119,438
Members
448,897
Latest member
dukenia71

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