+ Reply to Thread
Results 1 to 5 of 5

Index Match Large & Duplicates

  1. #1
    Registered User
    Join Date
    08-19-2015
    Location
    Anywhere
    MS-Off Ver
    Office 2007
    Posts
    7

    Index Match Large & Duplicates

    Hello!

    I have a list of names and scores. I'm trying to create a sort of "ranking" board where the top 4 people with the highest scores are printed (in order). Same for the bottom 4.

    Sample Data:

    Column A Column B
    James 10
    John 5
    Kim 8
    Carli 8
    David 8
    Daniel 9
    Eliza 3

    The results I'm looking for are:

    James
    Daniel
    Carli
    David

    The results I'm getting are:

    James
    Daniel
    Carli
    Carli

    This is the code I'm using
    Please Login or Register  to view this content.
    Where am I going wrong? I've experimented with IF, ROWS.. I don't want to add a helper column since the formatting is important. Any "elegant" fixes?

    Thank you!!
    Lux

  2. #2
    Forum Expert daddylonglegs's Avatar
    Join Date
    01-14-2006
    Location
    England
    MS-Off Ver
    2016
    Posts
    14,675

    Re: Index Match Large & Duplicates

    Assuming names in A2:A8 and scores in B2:B8 then one approach is as follows:

    Get the top 4 scores in E2:E5 by putting this formula in E2 and copying down to E5

    =LARGE(B$2:B$8,ROWS(E$2:E2))

    and then for the names - without duplicates - use this formula in F2 copied down

    =INDEX(A$2:A$8,AGGREGATE(15,6,(ROW(B$2:B$8)-ROW(B$2)+1)/(B$2:B$8=E2),COUNTIF(E$2:E2,E2)))
    Audere est facere

  3. #3
    Registered User
    Join Date
    08-19-2015
    Location
    Anywhere
    MS-Off Ver
    Office 2007
    Posts
    7

    Re: Index Match Large & Duplicates

    That worked perfectly Thank you!

    If you don't mind, would you be able to explain the functions used to me? I tried figuring it out myself, but I'm not sure I'm understanding why it works correctly.

    Thank you again!
    Lux

  4. #4
    Forum Expert daddylonglegs's Avatar
    Join Date
    01-14-2006
    Location
    England
    MS-Off Ver
    2016
    Posts
    14,675

    Re: Index Match Large & Duplicates

    I assume the first formula is straightforward, ROWS function increments by 1 every row so you get the largest n values (in order) if you copy down n rows

    With this formula

    =INDEX(A$2:A$8,AGGREGATE(15,6,(ROW(B$2:B$8)-ROW(B$2)+1)/(B$2:B$8=E2),COUNTIF(E$2:E2,E2)))

    the AGGREGATE function lets you use multiple functions, specified by the first argument, so 15 is the equivalent of SMALL function, 6 means errors are ignored (see Excel help on AGGREGATE for all the possible functions and codes).

    The next part is the array itself - ROW(B$2:B$8)-ROW(B$2)+1 gives you a simple 1 to n array of numbers where n is the number of rows in the range, so here that gives us this array

    {1;2;3;4;5;6;7}

    and we divide that by another array generated by (B$2:B$8=E2).....which will give us an array of TRUE or FALSE values. In your example E2 is the largest value, 10, and that only appears once in B2:B8, in the first position so that generates this array:

    {TRUE;FALSE;FALSE;FALSE;FALSE;FALSE;FALSE}

    When we divide the first array by the second we get another 7 element array which is each element of the first array divided by each element (in the same order) of array two.....and when you use mathematical operations on Boolean values TRUE becomes 1 and FALSE becomes 0, so the resulting array is all errors except for the first element where 1/TRUE = 1/1 = 1 hence

    {1;#DIV/0!;#DIV/0!;#DIV/0!;#DIV/0!;#DIV/0!;#DIV/0!}

    [Note: you can see these arrays yourself by highlighting the relevant part of the formula in the formula bar and pressing F9 key]

    Note that back at the start we said that the 6 in AGGREGATE function tells it to ignore errors, so we only have one number here, 1 and the COUNTIF formula in this row is

    COUNTIF(E$2:E2,E2)....which must return 1, so our whole aggregate function looks like this:

    AGGREGATE(15,6,{1;#DIV/0!;#DIV/0!;#DIV/0!;#DIV/0!;#DIV/0!;#DIV/0!},1)

    so that means we take the kth smallest value from that array, with the k value being the 1 at the end supplied by COUNTIF....so that's 1 and when we pass that 1 to the INDEX function it finds the value at that position (1) in A2:A8....i.e. James

    Now this is relatively simple for James because there is only one row with 10, our aggregate functions finds that row (1) and the INDEX function gives us the name......and also for the next row where there is only one 9 and the formula will find the related name (Daniel).....but what happens on row 4 where we have the first of the three 8s in E4 and the formula looks like this:

    =INDEX(A$2:A$8,AGGREGATE(15,6,(ROW(B$2:B$8)-ROW(B$2)+1)/(B$2:B$8=E4),COUNTIF(E$2:E4,E4)))

    because there are 3 instances of 8 we now get 3 row numbers in the array, like this

    AGGREGATE(15,6,{#DIV/0!;#DIV/0!;3;4;5;#DIV/0!;#DIV/0!},COUNTIF(E$2:E4,E4))

    ....and note that as we drag the formula down the range in the COUNTIF formula is expanding, so it counts all the 8s on the current row and above, on row 4 that's 1 again so from that array it still select the smallest value, which is 3, with associated name Kim, but the clever part is that on row 5 where E5 = 8 again that same array with 3, 4 and 5 is generated...but COUNTIF now results in the value 2 (because E4 and E5 are both 8) so instead of taking the value 3 again (which would result in a duplicate name) the formula this time has 2 as the k value and therefore returns 4 and INDEX returns Carli.

    This will work correctly for any number of duplicate values.

    Before AGGREGATE function was added in Excel 2010 you could do a similar thing with SMALL function instead of AGGREGATE but typically AGGREGATE doesn't require "array entry" so is probably preferable unless you are using an older Excel version
    Last edited by daddylonglegs; 11-15-2017 at 07:32 PM.

  5. #5
    Forum Contributor
    Join Date
    03-05-2015
    Location
    norwich
    MS-Off Ver
    365
    Posts
    107

    Re: Index Match Large & Duplicates

    How would you do this using 2007? Where aggregate has not quite been invented yet!!

+ 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] Accounting for duplicates with LARGE function (within index match)
    By quart in forum Excel Formulas & Functions
    Replies: 4
    Last Post: 04-28-2017, 10:38 AM
  2. Issue with LARGE, MATCH, INDEX and duplicates, multiple conditions
    By Toddowhams in forum Excel Formulas & Functions
    Replies: 5
    Last Post: 01-05-2017, 03:08 PM
  3. INDEX/MATCH with =LARGE is giving duplicates
    By keith740 in forum Excel General
    Replies: 6
    Last Post: 10-07-2015, 03:35 AM
  4. [SOLVED] Problem Using LARGE formula with Index/Match to pull values when there are Duplicates
    By BDavis in forum Excel Formulas & Functions
    Replies: 9
    Last Post: 08-11-2014, 02:23 PM
  5. [SOLVED] Large,Index, Match with duplicates
    By x65140 in forum Excel Programming / VBA / Macros
    Replies: 3
    Last Post: 02-10-2014, 10:45 AM
  6. Match/Large with Duplicates (I want to include the duplicates)
    By Willie68 in forum Excel Formulas & Functions
    Replies: 1
    Last Post: 08-13-2013, 01:10 PM

Tags for this Thread

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