Passing range parameters to VLOOKUP

tonySA

New Member
Joined
May 12, 2002
Messages
22
Hi fellow excellers

I want to pass a cell reference that contains the name of a worksheet and range to a VLOOKUP type function. Is it possible ?

eg I have 3 worksheets may, june and july each with range A1:B6. Column A is constant across all sheets but B contains differing monthly data that I want to pass to another sheet.

In 4th worksheet "Report" (say) I want the user to enter into cell A5 the respective worksheet name (may, june or july) and range parameters and for various VLOOKUP (or other) functions to use this info to retrieve the data from the respective worksheet.

I searched this site but couldn't find anything that seemed to fit the bill although there was one post that used INDEX and MATCH which may prove useful, otherwise I'll have to use a macro.

Any ideas ?

Thanks

Tony
 

Excel Facts

Pivot Table Drill Down
Double-click any number in a pivot table to create a new report showing all detail rows that make up that number
What follows shows how VLOOKUP can be fed a different sheet name to retrieve info from that sheet:

{"","","";
"","","";
"Enter","Look Up","";
"Month","What?","";
"May","dax",20}

which is in A3:C5.

The formula in C5 is:

=IF(COUNTIF(INDIRECT("'"&A5&"'!$A$1:$A$6"),B5),VLOOKUP(B5,INDIRECT("'"&A5&"'!$A$1:$B$6"),2,0),"No info on "&B5)

which shows the use of INDIRECT within VLOOKUP.
 
Upvote 0
How about using the choose command ?
Code:
=CHOOSE(B4,VLOOKUP(B3,Jun!A1:B5,2,FALSE),VLOOKUP(B3,Jul!A1:B6,2,FALSE),VLOOKUP(B3,Aug!A1:B6,2,FALSE))

B4= where you choose which month to use 1,2,3
( instead of number you can also use a drop down list with month names and us "lookup" to translate into the appropriate number.

B3= the search string to lookfor in arrays
 
Upvote 0
Hi there

You might also try pasting this formula in cell B1 of the sheet Report and scrolling it down. If you type June in column A it will return the corresponding entry for that row.

=INDIRECT(A1&"!B"&ROW())

Regards
Derek
 
Upvote 0
Thanks for all your input, much appreciated.
I used the INDIRECT function and it worked a treat. Very useful function !

Cheers
Tony
 
Upvote 0

Forum statistics

Threads
1,213,496
Messages
6,113,995
Members
448,539
Latest member
alex78

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