+ Reply to Thread
Results 1 to 7 of 7

VLOOKUP or INDEX/MATCH?

  1. #1
    Registered User
    Join Date
    11-16-2011
    Location
    New York, NY
    MS-Off Ver
    Excel 2010
    Posts
    4

    VLOOKUP or INDEX/MATCH?

    Hello,

    I have a look up table that I would like to populate with where a client was in the pipeline on a particular date. I would like to do a VLOOKUP on my activity table, but only look for entries prior to a given date. Does anyone have any suggestions? I have attached a sample file.

    Thank you!
    Attached Files Attached Files

  2. #2
    Forum Expert NBVC's Avatar
    Join Date
    12-06-2006
    Location
    Mississauga, CANADA
    MS-Off Ver
    2003:2010
    Posts
    34,898

    Re: VLOOKUP or INDEX/MATCH?

    Are you trying to count matches to the first 2 columns and then date in first row.

    like:

    =COUNTIFS(Activity!$A$2:$A$8,$A2,Activity!$B$2:$B$8,$B2,Activity!$C$2:$C$8,C$1)

    copied down and across.
    Where there is a will there are many ways.

    If you are happy with the results, please add to the contributor's reputation by clicking the reputation icon (star icon) below left corner

    Please also mark the thread as Solved once it is solved. Check the FAQ's to see how.

  3. #3
    Registered User
    Join Date
    11-16-2011
    Location
    New York, NY
    MS-Off Ver
    Excel 2010
    Posts
    4

    Re: VLOOKUP or INDEX/MATCH?

    Sorry if I didn't describe properly what value I wanted to get back. I want to display the "Pipeline Stage" on or before a particular date.

    Example: If I did a VLOOKUP for LC1000117 in the activity table, I would get "Lost" for the "Pipeline Stage". VLOOKUP(A2,Activity!A:B,2,FALSE)
    What I want to know is what stage was it in on 11/14/2011. So I want to do a lookup but only of values where "ActivityDate" is <=11/14/2011.

    In my sample set the answer for LC1000117 on 11/14/2011 should be "No Reply".

  4. #4
    Forum Expert NBVC's Avatar
    Join Date
    12-06-2006
    Location
    Mississauga, CANADA
    MS-Off Ver
    2003:2010
    Posts
    34,898

    Re: VLOOKUP or INDEX/MATCH?

    Try:

    =IFERROR(INDEX(Activity!$B$2:$B$8,MATCH(1,INDEX((Activity!$A$2:$A$8=$A2)*(Activity!$C$2:$C$8=C$1),0),0)),"")

    copied down and across

  5. #5
    Registered User
    Join Date
    11-16-2011
    Location
    New York, NY
    MS-Off Ver
    Excel 2010
    Posts
    4

    Re: VLOOKUP or INDEX/MATCH?

    Thanks for the suggestion, but this still does not provide the appropriate values on dates that don't have records. For example, on 11/12/2011 the values should be identical to those on 11/11/2011 (as there was no activity on 11/12).

  6. #6
    Forum Expert NBVC's Avatar
    Join Date
    12-06-2006
    Location
    Mississauga, CANADA
    MS-Off Ver
    2003:2010
    Posts
    34,898

    Re: VLOOKUP or INDEX/MATCH?

    Okay then try:

    =IFERROR(INDEX(Activity!$B$2:$B$8,MIN(IF((Activity!$A$2:$A$8=$A2)*(Activity!$C$2:$C$8<=C$1), ROW(Activity!$B$2:$B$8)-ROW(Activity!$B$2)+1))),"")

    confirmed with CTRL+SHIFT+ENTER not just ENTER and copied down and across

  7. #7
    Registered User
    Join Date
    11-16-2011
    Location
    New York, NY
    MS-Off Ver
    Excel 2010
    Posts
    4

    Re: VLOOKUP or INDEX/MATCH?

    Worked like a charm!! Can't thank you enough.

+ 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