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
 

Some videos you may like

Excel Facts

When they said...
When they said you are going to "Excel at life", they meant you "will be doing Excel your whole life".

jc.021286

Well-known Member
Joined
Apr 12, 2010
Messages
725
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
 

Sandeep Warrier

Board Regularmmmm Pizza
Joined
Oct 31, 2008
Messages
2,672
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)
 

mgirvin

Well-known Member
Joined
Dec 15, 2005
Messages
1,213
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))
 

mgirvin

Well-known Member
Joined
Dec 15, 2005
Messages
1,213
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))
 

bosco_yip

Well-known Member
Joined
Dec 2, 2002
Messages
1,938
Office Version
2019
Platform
Windows
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:

Subscribe on YouTube

Watch MrExcel Video

Forum statistics

Threads
1,106,907
Messages
5,514,075
Members
408,983
Latest member
mlee13

This Week's Hot Topics

  • Sort code advice please
    Hi, I have the code below which im trying to edit but getting a little stuck. This was the original code which worked fine,columns A-F would sort...
  • SUMPRODUCT with nested If statement
    Hi everyone, Hope you're all well. I'm hoping someone will be able to point me in the right direction with a problem I'm having with a SUMPRODUCT...
  • VBA - simple sort is killing me!
    Hello all! This should be so easy, but not for me, apparently! I have a table of data that can be of varying lengths and widths. My current macro...
  • Compare Two Lists
    I have two Lists and I need to be able to Identify differences between them. List 100 comes from a workbook - the other is downloaded form the...
  • Formula that deducts points for each code I input.
    I am trying to create a formula that will have each student in my class start at 100 points and then for each code that I enter (PP for Poor...
  • Conditional formatting formula required for day of week and a value
    Hi, I have a really simple spreadsheet where column A is the date, column B is the activity total shown as a number and column C states the day of...
Top