Thanks Thanks:  0
Likes Likes:  0
Page 1 of 5 123 ... LastLast
Results 1 to 10 of 46

Thread: Double Vertical Lookup

  1. #1
    Board Regular
    Join Date
    Oct 2007
    Location
    Philadelphia
    Posts
    461
    Post Thanks / Like
    Mentioned
    0 Post(s)
    Tagged
    0 Thread(s)

    Default Double Vertical Lookup

    I can do a regular vertical lookup but not quite sure how to do a double vertical lookup. I need to look up the state and then the county within my table to find the correct deductible. The lookup value for the state is in cell A12 and the lookup value for the county is in cell A13. The data is in cell K12:N500. The state is in column K, location is in column L, county column M and deductible column N
    Ken

  2. #2
    Board Regular Weazel's Avatar
    Join Date
    Dec 2011
    Location
    Florida
    Posts
    3,155
    Post Thanks / Like
    Mentioned
    0 Post(s)
    Tagged
    0 Thread(s)

    Default Re: Double Vertical Lookup

    you could probably do it with a sumifs assuming there aren't any duplicates

    I'm not really sure what 'location' is supposed to be.

    Excel 2012
    A B C D E F G H I J K L M N
    12 California $ 77,168.00
    13 Marin County State Location County Deductible
    14 Alaska ? Anchorage City $72,813
    15 Alaska ? Matanuska-Susitna Borough $68,672
    16 California ? Santa Clara County $84,895
    17 California ? San Mateo County $81,657
    18 California ? Marin County $77,168
    19 California ? Ventura County $74,623
    20 California ? Contra Costa County $74,353
    21 California ? Orange County $72,293
    22 California ? San Francisco County $69,894
    23 California ? Placer County $68,959
    24 California ? Alameda County $67,558
    Sheet5

    Worksheet Formulas
    Cell Formula
    B12 =SUMIFS(N14:N24,K14:K24,A12,M14:M24,A13)

  3. #3
    Board Regular
    Join Date
    Aug 2014
    Location
    London
    Posts
    90
    Post Thanks / Like
    Mentioned
    0 Post(s)
    Tagged
    0 Thread(s)

    Default Re: Double Vertical Lookup

    You could do a sumproduct. Something like: =sumproduct((k12:k500=a12)*(m12:m500=a13)*(n12:n500))

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

    Default Re: Double Vertical Lookup

    Quote Originally Posted by Tennisguuy View Post
    I can do a regular vertical lookup but not quite sure how to do a double vertical lookup. I need to look up the state and then the county within my table to find the correct deductible. The lookup value for the state is in cell A12 and the lookup value for the county is in cell A13. The data is in cell K12:N500. The state is in column K, location is in column L, county column M and deductible column N
    Control+shift+enter, not just enter:

    =IFERROR(INDEX($N$2:$N$100,MATCH(A13,IF($K$2:$K$100=A12,$M$2:$M$10),0)),0)
    Assuming too much and qualifying too much are two faces of the same problem.

  5. #5
    Board Regular
    Join Date
    Oct 2013
    Posts
    51
    Post Thanks / Like
    Mentioned
    0 Post(s)
    Tagged
    0 Thread(s)

    Default Re: Double Vertical Lookup

    Traditionally I use index/match instead of vlookup but regardless of what you use you just need to concatenate the lookup cells and the arrays something like INDEX($K$14:$N$24,MATCH($A$12&$A$13,$K$14:$K$24&$M$14:$M$24,0),4). remember to control+shift+enter.

  6. #6
    Board Regular
    Join Date
    Oct 2007
    Location
    Philadelphia
    Posts
    461
    Post Thanks / Like
    Mentioned
    0 Post(s)
    Tagged
    0 Thread(s)

    Default Re: Double Vertical Lookup

    Can it be done without using additional key strokes like control+shift+enter
    Ken

  7. #7
    Board Regular
    Join Date
    Oct 2013
    Posts
    51
    Post Thanks / Like
    Mentioned
    0 Post(s)
    Tagged
    0 Thread(s)

    Default Re: Double Vertical Lookup

    You have to use ctrl+shift+enter for array formulas. If you don't it won't work properly.

  8. #8
    Board Regular
    Join Date
    Oct 2013
    Posts
    51
    Post Thanks / Like
    Mentioned
    0 Post(s)
    Tagged
    0 Thread(s)

    Default Re: Double Vertical Lookup

    you can unlock the first two cells in the match however and if you have them in some sort of pattern then just drag the formula down reading the cell data and organizing it that way. Then you would only have to do that once.

  9. #9
    Board Regular
    Join Date
    Aug 2014
    Location
    London
    Posts
    90
    Post Thanks / Like
    Mentioned
    0 Post(s)
    Tagged
    0 Thread(s)

    Default Re: Double Vertical Lookup

    The sumproduct suggestion does not require an CSE formula.

  10. #10
    Board Regular
    Join Date
    Oct 2013
    Posts
    51
    Post Thanks / Like
    Mentioned
    0 Post(s)
    Tagged
    0 Thread(s)

    Default Re: Double Vertical Lookup

    The problem with the sumproduct is in the duplicates. The lookup functions are for specific criteria. Depending on what you enter, certain function would require you use that as well with sumproduct. Especially if entered in any type of if statement or other error checking. For better lookups and ones that don't care whether it is a number or not using the index/match or vlookup/hlookup is better.

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
  •