Closed Thread
Results 1 to 15 of 15

Yes another: VLOOKUP with multiple criteria question

  1. #1
    Forum Contributor
    Join Date
    07-27-2009
    Location
    montreal, canada
    MS-Off Ver
    Excel 2003
    Posts
    230

    Yes another: VLOOKUP with multiple criteria question

    I know,
    I've seen plenty already, but for the life of me, I don't understand how the INDEX/MATCH formula applies for my question, and the concecate method returns irrate values.


    I want my suppliers to fill in the
    Colomn A: Client #
    Colomn B: Subdivision

    And magically they will have the Client name appear in Colomn C.
    My array table is on sheet 2, hidden, A2:C472.

    I haven't placed this on my exemple, but I have data validation from a list (of unique records) for my client # and Subdivision. I don't think it will affect anything though.


    Can anyone help me on this?
    Attached Files Attached Files
    Last edited by Sibrulotte; 08-07-2009 at 02:17 PM.

  2. #2
    Valued Forum Contributor
    Join Date
    07-29-2009
    Location
    Belgium
    MS-Off Ver
    Excel 2003/Excel 2010
    Posts
    534

    Re: Yes another: VLOOKUP with multiple criteria question

    Like this?
    Attention: array formulas in C2, C3, etc. Enter with ctrl+shift+enter.
    Attached Files Attached Files

  3. #3
    Forum Expert JBeaucaire's Avatar
    Join Date
    03-21-2004
    Location
    Bakersfield, CA
    MS-Off Ver
    2010, 2016, Office 365
    Posts
    33,492

    Re: Yes another: VLOOKUP with multiple criteria question

    Put this non-array formula into cell C2 on sheet1 and then copy down:

    =IF(OR(A2="",B2=""), "", INDEX(Sheet2!$C$1:$C$500,MATCH(A2 & B2, INDEX(Sheet2!$A$1:$A$500 & Sheet2!$B$1:$B$500,0),0)))




    On Sheet2, you're missing a code in B471.

    Use this version if you want to continue using some values in only column A, leaving some blanks in B:

    =IF(A2="", "", INDEX(Sheet2!$C$1:$C$500, MATCH(A2 & B2, INDEX(Sheet2!$A$1:$A$500 & Sheet2!$B$1:$B$500,0), 0)))
    Last edited by JBeaucaire; 08-06-2009 at 05:47 PM.
    _________________
    Microsoft MVP 2010 - Excel
    Visit: Jerry Beaucaire's Excel Files & Macros

    If you've been given good help, use the icon below to give reputation feedback, it is appreciated.
    Always put your code between code tags. [CODE] your code here [/CODE]

    ?None of us is as good as all of us? - Ray Kroc
    ?Actually, I *am* a rocket scientist.? - JB (little ones count!)

  4. #4
    Forum Contributor
    Join Date
    07-27-2009
    Location
    montreal, canada
    MS-Off Ver
    Excel 2003
    Posts
    230

    Re: Yes another: VLOOKUP with multiple criteria question

    Thanks,

    Unfortunatly I am a complete retard.

    WHER: When I copy your formula to the notepad, and recopy to paste in my real spreadsheet with the real columns (Colomn A is in D, in B is in E, the rest is the same), and I change my A to a D, and my B to an E; I press CTRL+Shift+Enter, and I see the formula as if I had the VIEW FORMULA checked in view Options.


    JBeaucaire: I get an "error in the formula" right where the first Hyphens are.


    I thought i was smarter. I actually understand how the formula works, i just can't get it to stick. (In both cases)
    Attached Files Attached Files
    Last edited by Sibrulotte; 08-07-2009 at 10:02 AM.

  5. #5
    Valued Forum Contributor
    Join Date
    07-29-2009
    Location
    Belgium
    MS-Off Ver
    Excel 2003/Excel 2010
    Posts
    534

    Re: Yes another: VLOOKUP with multiple criteria question

    Here's what i would do to copy my formula: select cell C3 of Sheet1, then in the formulabar place the cursor in front of the (=)equal sign, type a single quote ('), hit enter. The formula is now text, copy this text, paste in your workbook in the appropriate cell, remove single quote at the front, replace colums in formula as needed, enter as array formula.

  6. #6
    Forum Contributor
    Join Date
    07-27-2009
    Location
    montreal, canada
    MS-Off Ver
    Excel 2003
    Posts
    230

    Re: Yes another: VLOOKUP with multiple criteria question

    thanks, it sticks, but I get an n/A value.
    My array table is in the same place...

  7. #7
    Valued Forum Contributor
    Join Date
    07-29-2009
    Location
    Belgium
    MS-Off Ver
    Excel 2003/Excel 2010
    Posts
    534

    Re: Yes another: VLOOKUP with multiple criteria question

    Looking at your "Gabarit" file, i noticed two small typing errors in your formula:
    this part Sheet2!$A$2;$A$472&Sheet2!$B2:$B$472 should be
    Sheet2!$A$2:$A$472&Sheet2!$B$2:$B$472

  8. #8
    Forum Expert JBeaucaire's Avatar
    Join Date
    03-21-2004
    Location
    Bakersfield, CA
    MS-Off Ver
    2010, 2016, Office 365
    Posts
    33,492

    Re: Yes another: VLOOKUP with multiple criteria question

    I just put my formula straight into your sheet and changed the columns, works fine. Not sure what the issue is.
    Attached Files Attached Files

  9. #9
    Registered User
    Join Date
    08-15-2008
    Location
    denver
    Posts
    68

    Re: Yes another: VLOOKUP with multiple criteria question

    Let me jump in here with a related, or perhaps the same question.

    I have always used concatination for lookups with multiple criteria very successfully. But just because I like to know how things work, I am trying to duplicate your INDEX/MATCH function.

    Wher - I have downloaded your workbook and have attempted to duplicate your index/match formula, but it doesn't work - I get a return of N/A. The only difference I see is that when I select one of the cells with your index/match formula, in the formula bar, the formula is enclosed in brackets {}. If I go to EDIT mode <F2>, the brackets dasappear. I can't duplicate those brackets, without the formula reverting to text.

    Can you help me out here?

    Thanks

  10. #10
    Forum Contributor
    Join Date
    07-27-2009
    Location
    montreal, canada
    MS-Off Ver
    Excel 2003
    Posts
    230

    Re: Yes another: VLOOKUP with multiple criteria question

    Thanks,
    It works great.

    approved of you guys.
    How do mark it solved?

  11. #11
    Forum Expert JBeaucaire's Avatar
    Join Date
    03-21-2004
    Location
    Bakersfield, CA
    MS-Off Ver
    2010, 2016, Office 365
    Posts
    33,492

    Re: Yes another: VLOOKUP with multiple criteria question

    If that takes care of your need, be sure to EDIT your original post, click Go Advanced and mark the PREFIX box [SOLVED].


    (Also, use the blue "scales" icon in our posts to leave Reputation Feedback, it is appreciated)

  12. #12
    Forum Expert JBeaucaire's Avatar
    Join Date
    03-21-2004
    Location
    Bakersfield, CA
    MS-Off Ver
    2010, 2016, Office 365
    Posts
    33,492

    Re: Yes another: VLOOKUP with multiple criteria question

    Quote Originally Posted by jmhultin View Post
    Wher - I have downloaded your workbook and have attempted to duplicate your index/match formula, but it doesn't work - I get a return of N/A. The only difference I see is that when I select one of the cells with your index/match formula, in the formula bar, the formula is enclosed in brackets {}. If I go to EDIT mode <F2>, the brackets dasappear. I can't duplicate those brackets, without the formula reverting to text.
    As described in WHER's post, his formula is an ARRAY formula. When you edit it, you must press CTRL-SHIFT-ENTER (CSE) to reactivate the array, just pressing ENTER breaks the array and you get an error, or worse you get a false answer.

    As you play with his sheet, use CSE to confirm all your changes and Excel will add the curly braces {} to prove the array is active.

    Be sure to try my very similar but non-CSE formulas, too. Whenever there is a non-array-entered solution, you should use it. CSE formulas multiply the calculations in a cell exponentially and should be avoided every time they can be. There are some situations where CSE is the only way, and as long as there aren't 100s of those cells, you should be fine, but for large datasets they should be avoided.

  13. #13
    Registered User
    Join Date
    08-15-2008
    Location
    denver
    Posts
    68

    Re: Yes another: VLOOKUP with multiple criteria question

    Thanks - that works!

  14. #14
    Registered User
    Join Date
    03-25-2012
    Location
    Noida, India
    MS-Off Ver
    Excel 2007
    Posts
    1

    Re: Yes another: VLOOKUP with multiple criteria question

    Index & Match works only if array is fixed i.e.
    If I have Item/Rate/date (wef date of Rate)
    In this scenario does vlookup work with multiple criteria?
    Where date (wef) is not always equal to current date, but can be greater than or less than the date(wef).
    Pls let me know thanks.
    Attached Files Attached Files

  15. #15
    Forum Expert Paul's Avatar
    Join Date
    02-05-2007
    Location
    Wisconsin
    MS-Off Ver
    2016/365
    Posts
    6,885

    Re: Yes another: VLOOKUP with multiple criteria question

    Hi DH_Sandy, welcome to the Forum, unfortunately:

    Your post does not comply with Rule 2 of our Forum RULES. Don't post a question in the thread of another member -- start your own thread. If you feel it's particularly relevant, provide a link to the other thread. It makes sense to have a new thread for your question because a thread with numerous replies can be off putting & difficult to pick out relevant replies.

Closed 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