+ Reply to Thread
Results 1 to 6 of 6

Lookup X-th value that matches criteria

  1. #1
    Registered User
    Join Date
    03-26-2015
    Location
    Netherlands
    MS-Off Ver
    2013
    Posts
    75

    Lookup X-th value that matches criteria

    Hi all,

    I'm looking for a formula that looks up the 'X'th (e.g. 3th) value that matches a criteria. This is the data:

    PHP Code: 
    Failure date    Location    departure date
    03
    -01-15    London    ?????????
    03-01-15    Paris    ?????????
    05-01-15    London    ?????????
    10-01-15    London    ?????????
    14-01-15    London    ?????????
    14-01-15    Paris    ?????????
    27-01-15    Paris    ????????? 
    Failures occur at multiple locations but flying to each location is expensive. So we only fly when multiple failures have occured, this is the ''batch threshold''. In this example the batch threshold for London is ''3''. So at 03-01-15 the first failure occurs, but the departure date should be the failure date of the third London failure. So in column C (departure date) it should return the date '10-01-15'. If the batch threshold was ''4'' then it would be '14-01-15'. Is it possible to put this into a formula?
    Last edited by Ronnet2; 10-28-2015 at 10:44 AM.

  2. #2
    Forum Moderator Glenn Kennedy's Avatar
    Join Date
    07-08-2012
    Location
    Digital Nomad... occasionally based in Ireland.
    MS-Off Ver
    O365 (PC) V 2403
    Posts
    44,063

    Re: Lookup X-th value that matches criteria

    Is this array formula what you wanted:

    =IFERROR(INDEX($A$2:$A$8,SMALL(IF($F3=$B$2:$B$8,ROW($B$2:$B$8)-ROW($A$2)+1),$G$2)),"")

    Array Formulae are a little different from ordinary formulas in that they MUST be confirmed by pressing CTRL+SHIFT+ENTER to activate the array, not just ENTER.

    You will know the array is active when you see curly braces { } appear around the outside of your formula. If you do not CTRL+SHIFT+ENTER you will (almost always) get an error message or an incorrect answer. Press F2 on that cell and try again.

    Don't type the curly braces yourself - it won't work...
    Attached Files Attached Files
    Glenn




    None of us get paid for helping you... we do this for fun. So DON'T FORGET to say "Thank You" to all who have freely given some of their time to help YOU.

    Temporary addition of accented to illustrate ongoing problem to the TT: L? fh?ile P?draig sona dhaoibh

  3. #3
    Registered User
    Join Date
    03-26-2015
    Location
    Netherlands
    MS-Off Ver
    2013
    Posts
    75

    Re: Lookup X-th value that matches criteria

    Thanks for the formula! It seems to do the trick but I´m wondering whether I can do this without using an arrray formula. The formula needs to be pasted downwards in column C (the question marks). So the cell reference from the top must be variable. Like this:

    =IFERROR(INDEX(A2:$A$8;SMALL(IF($B2=B2:$B$8;ROW(B2:$B$8)-ROW($A2)+1);$E$1));"")

    (i.e. The A2 and B2 in the ranges are not fixed)

    The problem is that I will have hundreds of these different oneline arrays pasted downwards. I´m wondering whether that won´t unnecesarrily bog down my sheet .

  4. #4
    Forum Expert
    Join Date
    05-30-2012
    Location
    The Netherlands
    MS-Off Ver
    Office 365
    Posts
    14,987

    Re: Lookup X-th value that matches criteria

    with countif (aantal.als) and a filter on the 3th value.

    see the attached file.
    Notice my main language is not English.

    I appreciate it, if you reply on my solution.

    If you are satisfied with the solution, please mark the question solved.

    You can add reputation by clicking on the star * add reputation.

  5. #5
    Forum Moderator Glenn Kennedy's Avatar
    Join Date
    07-08-2012
    Location
    Digital Nomad... occasionally based in Ireland.
    MS-Off Ver
    O365 (PC) V 2403
    Posts
    44,063

    Re: Lookup X-th value that matches criteria

    ... or

    =IF(COUNTIF($B$2:$B2,$B2)=$I$2,COUNTIF($B$2:$B2,$B2),"")

    where I2 = Batch threshold. In this case there is no need to apply any filter.

  6. #6
    Forum Guru
    Join Date
    08-05-2004
    Location
    NJ
    MS-Off Ver
    365
    Posts
    13,582

    Re: Lookup X-th value that matches criteria

    So the cell reference from the top must be variable
    So are you saying that in your example, (using Glen's sheet for reference), in C2 = 1/10/2015 (m/d/yyyy), C4 will be 1/14/2015 but there will be nothing in C5 or C6 because there are not 3 failed flights from that date?

    I don't know that you can do it without arrays without a lot of manipulation that might slow you down just as much.
    ChemistB
    My 2?

    substitute commas with semi-colons if your region settings requires
    Don't forget to mark threads as "Solved" (Edit First post>Advanced>Change Prefix)
    If I helped, Don't forget to add to my reputation (click on the little star at bottom of this post)

    Forum Rules: How to use code tags, mark a thread solved, and keep yourself out of trouble

+ Reply to Thread

Thread Information

Users Browsing this Thread

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

Similar Threads

  1. [SOLVED] Lookup Values which meet two or more criteria and return multiple matches horizontally
    By josetmg in forum Excel Formulas & Functions
    Replies: 7
    Last Post: 02-03-2015, 01:16 AM
  2. Creating a three way lookup with columns and row lookup matches
    By jimbob23 in forum Excel Formulas & Functions
    Replies: 9
    Last Post: 12-19-2014, 10:58 PM
  3. [SOLVED] Lookup with multiple criteria and matches
    By pmeans in forum Excel Formulas & Functions
    Replies: 6
    Last Post: 01-30-2013, 04:58 PM
  4. Lookup with multiple criteria and matches
    By cplian in forum Excel Formulas & Functions
    Replies: 2
    Last Post: 04-29-2011, 01:52 AM
  5. Lookup several possible matches
    By Jasonr in forum Excel General
    Replies: 2
    Last Post: 12-06-2010, 09:56 AM
  6. [SOLVED] V-lookup and summing values if more than 1 matches criteria
    By holcay in forum Excel Formulas & Functions
    Replies: 3
    Last Post: 02-06-2006, 11:55 AM
  7. [SOLVED] Is it possible to do a vertical lookup that matches on 2 criteria
    By lshaw in forum Excel Formulas & Functions
    Replies: 4
    Last Post: 05-16-2005, 02:06 PM

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