Error Checking in Excel
Thanks Thanks:  0
Likes Likes:  0
Results 1 to 5 of 5

Thread: Passing range parameters to VLOOKUP

  1. #1
    New Member
    Join Date
    May 2002
    Location
    Adelaide, South Australia
    Posts
    22
    Post Thanks / Like
    Mentioned
    0 Post(s)
    Tagged
    0 Thread(s)

    Default

    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


  2. #2
    MrExcel MVP Aladin Akyurek's Avatar
    Join Date
    Feb 2002
    Location
    The Hague, NL
    Posts
    84,063
    Post Thanks / Like
    Mentioned
    38 Post(s)
    Tagged
    8 Thread(s)

    Default

    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.


  3. #3
    MrExcel MVP
    Join Date
    Apr 2002
    Location
    Vancouver BC , Canada
    Posts
    6,259
    Post Thanks / Like
    Mentioned
    0 Post(s)
    Tagged
    0 Thread(s)

    Default

    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

  4. #4
    Board Regular
    Join Date
    Feb 2002
    Location
    Perth Australia
    Posts
    1,584
    Post Thanks / Like
    Mentioned
    0 Post(s)
    Tagged
    0 Thread(s)

    Default

    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

  5. #5
    New Member
    Join Date
    May 2002
    Location
    Adelaide, South Australia
    Posts
    22
    Post Thanks / Like
    Mentioned
    0 Post(s)
    Tagged
    0 Thread(s)

    Default

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

    Cheers
    Tony

Some videos you may like

User Tag List

Like this thread? Share it with others

Like this thread? Share it with others

Posting Permissions

  • You may not post new threads
  • You may not post replies
  • You may not post attachments
  • You may not edit your posts
  •