+ Reply to Thread
Results 1 to 4 of 4

Reading a defined range name from a cell for fomula input

Hybrid View

  1. #1
    Registered User
    Join Date
    08-10-2009
    Location
    Houston, TX
    MS-Off Ver
    Excel 2003
    Posts
    2

    Reading a defined range name from a cell for fomula input

    I've got a worksheet with several tables, each of which I've assigned a defined name. At the top of my worksheet I have several cells containing lookup functions, and these are repeated for each defined table on the sheet.

    Right now I'm creating all my lookup functions for a single table, copying the cells containing these functions, and editing the references to the defined names in the copies by hand, giving me a final product something like this:

                          A                       B                      C                      D
    1
    2                    10                      10                     10                     10
    3 =VLOOKUP(A$2,Table1,2) =VLOOKUP(B$2,Table2,2) =VLOOKUP(C$2,Table3,2) =VLOOKUP(D$2,Table4,2)
    4 =VLOOKUP(A$2,Table1,3) =VLOOKUP(B$2,Table2,3) =VLOOKUP(C$2,Table3,3) =VLOOKUP(D$2,Table4,3)
    5 =VLOOKUP(A$2,Table1,4) =VLOOKUP(B$2,Table2,4) =VLOOKUP(C$2,Table3,4) =VLOOKUP(D$2,Table4,4)
    6 =VLOOKUP(A$2,Table1,5) =VLOOKUP(B$2,Table2,5) =VLOOKUP(C$2,Table3,5) =VLOOKUP(D$2,Table4,5)
    To get this result, I'd normally do all the formulas in Column A first, then copy these formulas to Columns B-D, but doing that gives me the result below:
                          A                       B                      C                      D
                          A                       B                      C                      D
    1
    2                    10                      10                     10                     10
    3 =VLOOKUP(A$2,Table1,2) =VLOOKUP(B$2,Table1,2) =VLOOKUP(C$2,Table1,2) =VLOOKUP(D$2,Table1,2)
    4 =VLOOKUP(A$2,Table1,3) =VLOOKUP(B$2,Table1,3) =VLOOKUP(C$2,Table1,3) =VLOOKUP(D$2,Table1,3)
    5 =VLOOKUP(A$2,Table1,4) =VLOOKUP(B$2,Table1,4) =VLOOKUP(C$2,Table1,4) =VLOOKUP(D$2,Table1,4)
    6 =VLOOKUP(A$2,Table1,5) =VLOOKUP(B$2,Table1,5) =VLOOKUP(C$2,Table1,5) =VLOOKUP(D$2,Table1,5)
    As you can see, I still have to go in to Columns B-D and manually correct the table reference names. So, my question is this: is it possible to enter the text values Table1, Table2, etc. in Row 1, and somehow have all my vlookup functions extract the name of the table to use from these cells? I know I can't just do something like having the formula in A3 =VLOOKUP(A$2,A$1,2) since that will make the formula think that the range A1 itself is where I want to do the lookup. Any ideas?

  2. #2
    Forum Guru DonkeyOte's Avatar
    Join Date
    10-22-2008
    Location
    Northumberland, UK
    MS-Off Ver
    O365
    Posts
    21,531

    Re: Reading a defined range name from a cell for fomula input

    If you were to store the appropriate table name in one cell in each column (common row) you could use INDIRECT ... eg say A1 contained Table1, B1 Table2 etc then you can use INDIRECT such that:

    A3:=VLOOKUP(A$2,INDIRECT(A$1),ROWS(A$2:A3))

    and copy that across your entire matrix HOWEVER note that INDIRECT is a Volatile function and performance can be affected when used en masse - for more info on Volatility see the link in my sig to Charles Williams' site.

  3. #3
    Registered User
    Join Date
    08-10-2009
    Location
    Houston, TX
    MS-Off Ver
    Excel 2003
    Posts
    2

    Re: Reading a defined range name from a cell for fomula input

    Thanks, INDIRECT() is just what I needed.

  4. #4
    Forum Guru DonkeyOte's Avatar
    Join Date
    10-22-2008
    Location
    Northumberland, UK
    MS-Off Ver
    O365
    Posts
    21,531

    Re: Reading a defined range name from a cell for fomula input

    Yes note also use of ROWS to increment your column reference in the VLOOKUP as you copy the formula in vertical direction.

    Don't underestimate the impact of Volatile functions on performance however...
    Last edited by DonkeyOte; 08-10-2009 at 01:31 PM. Reason: horizontal ? I think not doofus...

+ Reply to Thread

Thread Information

Users Browsing this Thread

There are currently 1 users browsing this thread. (0 members and 1 guests)

Bookmarks

Posting Permissions

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

Search Engine Friendly URLs by vBSEO 3.6.0 RC 1