+ Reply to Thread
Results 1 to 17 of 17

Indexing correct match using LARGE formula with criteria

  1. #1
    Registered User
    Join Date
    04-16-2019
    Location
    Sleaford
    MS-Off Ver
    O365
    Posts
    78

    Indexing correct match using LARGE formula with criteria

    Good Morning,

    Happy Friday who is working, who has a day off, enjoy it!

    I'm coming for help because I couldn't figure this out myself.

    What is the issue? - I'm using INDEX, MATCH, LARGE functions together to INDEX the LARGEST valued data from specific column. The issue happens if in the criteria range there is multiple data entries with the same value. Then using LARGE,1 and LARGE,2 I receive the same outcome from both lines (duplicate). I would like to always get unique data even if values from criteria range are the same.

    I will attach a sample workbook to understand the situation better.

    Untitled4.png

    Here you can see that the Material with description 1 is on both lines, that shouldn't happen.

    Because If we are looking in the data where it comes from:

    Untitled1.png
    Then value for Description 2 is the same as Description 1.

    here is the formula used on 2nd row:
    Please Login or Register  to view this content.
    Attached Files Attached Files

  2. #2
    Forum Moderator AliGW's Avatar
    Join Date
    08-10-2013
    Location
    Retired in Ipswich, Suffolk, but grew up in Sawley, Derbyshire (England)
    MS-Off Ver
    MS 365 Subscription Insider Beta Channel v. 2404 (Windows 11 22H2 64-bit)
    Posts
    80,916

    Re: Indexing correct match using LARGE formula with criteria

    Please show us the results you want (mock them up manually) rather than a non-functioning and very lengthy (not going to try to reverse engineer it!) formula. You haven't explained what the logic should be.
    Ali


    Enthusiastic self-taught user of MS Excel who's always learning!
    Don't forget to say "thank you" in your thread to anyone who has offered you help.
    You can reward them by clicking on * Add Reputation below their user name on the left, if you wish.

    Forum Rules (updated August 2023): please read them here.

  3. #3
    Forum Moderator AliGW's Avatar
    Join Date
    08-10-2013
    Location
    Retired in Ipswich, Suffolk, but grew up in Sawley, Derbyshire (England)
    MS-Off Ver
    MS 365 Subscription Insider Beta Channel v. 2404 (Windows 11 22H2 64-bit)
    Posts
    80,916

    Re: Indexing correct match using LARGE formula with criteria

    I'll have ONE guess! Is this what you are aiming for? It gets the top three.

    =TAKE(SORT('Paste-ZR63G'!A2:F5,6),3,1)
    Attached Files Attached Files
    Last edited by AliGW; 03-29-2024 at 04:20 AM.

  4. #4
    Forum Guru TMS's Avatar
    Join Date
    07-15-2010
    Location
    The Great City of Manchester, NW England ;-)
    MS-Off Ver
    MSO 2007,2010,365
    Posts
    44,463

    Re: Indexing correct match using LARGE formula with criteria

    With 365, this returns the expected results:
    Formula: copy to clipboard
    Please Login or Register  to view this content.
    Trevor Shuttleworth - Retired Excel/VBA Consultant

    I dream of a better world where chickens can cross the road without having their motives questioned

    'Being unapologetic means never having to say you're sorry' John Cooper Clarke


  5. #5
    Forum Moderator AliGW's Avatar
    Join Date
    08-10-2013
    Location
    Retired in Ipswich, Suffolk, but grew up in Sawley, Derbyshire (England)
    MS-Off Ver
    MS 365 Subscription Insider Beta Channel v. 2404 (Windows 11 22H2 64-bit)
    Posts
    80,916

    Re: Indexing correct match using LARGE formula with criteria

    Or maybe this?

    =TAKE(SORT(FILTER('Paste-ZR63G'!A2:F5,'Paste-ZR63G'!B2:B5="261"),6),3,1)

  6. #6
    Registered User
    Join Date
    04-16-2019
    Location
    Sleaford
    MS-Off Ver
    O365
    Posts
    78

    Re: Indexing correct match using LARGE formula with criteria

    Quote Originally Posted by AliGW View Post
    I'll have ONE guess! Is this what you are aiming for?

    =TAKE(SORT('Paste-ZR63G'!A2:F5,6),3,1)
    Quote Originally Posted by AliGW View Post
    Please show us the results you want (mock them up manually) rather than a non-functioning and very lengthy (not going to try to reverse engineer it!) formula. You haven't explained what the logic should be.
    I do apologise for not clearing things out.
    It must be: Attachment 864583

    The formula you provided indeed sorts the values correctly but I must implement this somehow in my active formula.

    I'll try it myself and will give feedback if I am successful.

  7. #7
    Forum Moderator AliGW's Avatar
    Join Date
    08-10-2013
    Location
    Retired in Ipswich, Suffolk, but grew up in Sawley, Derbyshire (England)
    MS-Off Ver
    MS 365 Subscription Insider Beta Channel v. 2404 (Windows 11 22H2 64-bit)
    Posts
    80,916

    Re: Indexing correct match using LARGE formula with criteria

    Post #5 is a REPLACEMEDNT for your rather long 'active' formula. I think it does the same thing. Look at the attachment.
    Attached Files Attached Files

  8. #8
    Forum Guru TMS's Avatar
    Join Date
    07-15-2010
    Location
    The Great City of Manchester, NW England ;-)
    MS-Off Ver
    MSO 2007,2010,365
    Posts
    44,463

    Re: Indexing correct match using LARGE formula with criteria

    Ah, got it:
    Formula: copy to clipboard
    Please Login or Register  to view this content.

  9. #9
    Forum Moderator AliGW's Avatar
    Join Date
    08-10-2013
    Location
    Retired in Ipswich, Suffolk, but grew up in Sawley, Derbyshire (England)
    MS-Off Ver
    MS 365 Subscription Insider Beta Channel v. 2404 (Windows 11 22H2 64-bit)
    Posts
    80,916

    Re: Indexing correct match using LARGE formula with criteria

    If you also need the value:

    =CHOOSECOLS(TAKE(SORT(FILTER('Paste-ZR63G'!A2:F5,'Paste-ZR63G'!B2:B5="261"),6),3),1,6)
    Attached Files Attached Files

  10. #10
    Forum Moderator AliGW's Avatar
    Join Date
    08-10-2013
    Location
    Retired in Ipswich, Suffolk, but grew up in Sawley, Derbyshire (England)
    MS-Off Ver
    MS 365 Subscription Insider Beta Channel v. 2404 (Windows 11 22H2 64-bit)
    Posts
    80,916

    Re: Indexing correct match using LARGE formula with criteria

    Or this, even:

    =CHOOSECOLS(TAKE(SORT(FILTER('Paste-ZR63G'!A2:F5,('Paste-ZR63G'!B2:B5="261")*(MID('Paste-ZR63G'!C2:C5,4,1)<>"3")),6),3),1,6)
    Attached Files Attached Files

  11. #11
    Registered User
    Join Date
    04-16-2019
    Location
    Sleaford
    MS-Off Ver
    O365
    Posts
    78

    Re: Indexing correct match using LARGE formula with criteria

    Quote Originally Posted by AliGW View Post
    Post #5 is a REPLACEMEDNT for your rather long 'active' formula. I think it does the same thing. Look at the attachment.
    I appreciate your solution, however, the reason why I must implement this into my formula or find another way is that the columns can often change their index. Sometimes Material can be at A column, sometimes at C column. That's why I'm using the Index Match to find the column by "column name". If we can insert that inside your formula then it would work 100%. I will try to work this out. Thank you

  12. #12
    Forum Moderator AliGW's Avatar
    Join Date
    08-10-2013
    Location
    Retired in Ipswich, Suffolk, but grew up in Sawley, Derbyshire (England)
    MS-Off Ver
    MS 365 Subscription Insider Beta Channel v. 2404 (Windows 11 22H2 64-bit)
    Posts
    80,916

    Re: Indexing correct match using LARGE formula with criteria

    This will find the columns by name:

    =CHOOSECOLS(TAKE(SORT(FILTER('Paste-ZR63G'!A2:F5,(FILTER('Paste-ZR63G'!A2:F5,'Paste-ZR63G'!A1:F1="MvT")="261")*(MID(FILTER('Paste-ZR63G'!A2:F5,'Paste-ZR63G'!A1:F1="Order"),4,1)<>"3")),6),3),1,6)

    In future, please explain the LOGIC of your requirements in WORDS instead of expecting us to reverse engineer a long formula.
    Attached Files Attached Files
    Last edited by AliGW; 03-29-2024 at 04:41 AM.

  13. #13
    Registered User
    Join Date
    04-16-2019
    Location
    Sleaford
    MS-Off Ver
    O365
    Posts
    78

    Re: Indexing correct match using LARGE formula with criteria

    Almost there, the last bit is that SORT index column could also change index so index "6" would not work in this case. Is there a solution without index match help?

    And yes, I do agree that I had to explain more detailed what I expect from the formula. I normally solve the issue myself but in this case I struggled and couldn't find a solution. I'm sorry I took to much of your time.
    Last edited by AliGW; 03-29-2024 at 04:48 AM. Reason: Please don't quote unnecessarily - use the Quick Reply button instead.

  14. #14
    Forum Moderator AliGW's Avatar
    Join Date
    08-10-2013
    Location
    Retired in Ipswich, Suffolk, but grew up in Sawley, Derbyshire (England)
    MS-Off Ver
    MS 365 Subscription Insider Beta Channel v. 2404 (Windows 11 22H2 64-bit)
    Posts
    80,916

    Re: Indexing correct match using LARGE formula with criteria

    And finally ...

    Please Login or Register  to view this content.
    Could have got this in one go IF you had explained the logic!
    Attached Files Attached Files

  15. #15
    Forum Moderator AliGW's Avatar
    Join Date
    08-10-2013
    Location
    Retired in Ipswich, Suffolk, but grew up in Sawley, Derbyshire (England)
    MS-Off Ver
    MS 365 Subscription Insider Beta Channel v. 2404 (Windows 11 22H2 64-bit)
    Posts
    80,916

    Re: Indexing correct match using LARGE formula with criteria

    One final tweak:

    Please Login or Register  to view this content.
    If that takes care of your original question, please choose Thread Tools from the menu link above and mark this thread as SOLVED. You can also access the SOLVED tag by editing the opening post and choosing SOLVED from the drop-down to the left of the title box.

    Also, if you have not already done so, remember that you can reward anyone who offered you help towards a solution for your issue by clicking the small star icon (* Add Reputation) located in the lower left corner of the post in which the help was given. By doing so you can add to the reputation(s) of each of those who offered help.
    Attached Files Attached Files
    Last edited by AliGW; 03-29-2024 at 05:09 AM.

  16. #16
    Registered User
    Join Date
    04-16-2019
    Location
    Sleaford
    MS-Off Ver
    O365
    Posts
    78

    Re: Indexing correct match using LARGE formula with criteria

    Thank you very much for your help!

  17. #17
    Forum Moderator AliGW's Avatar
    Join Date
    08-10-2013
    Location
    Retired in Ipswich, Suffolk, but grew up in Sawley, Derbyshire (England)
    MS-Off Ver
    MS 365 Subscription Insider Beta Channel v. 2404 (Windows 11 22H2 64-bit)
    Posts
    80,916

    Re: Indexing correct match using LARGE formula with criteria

    You're welcome.

+ 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. formula referencing (INDIRECT / VLOOKUP / INDEXING / MATCH?)
    By tennisfan33 in forum Excel Formulas & Functions
    Replies: 2
    Last Post: 07-16-2020, 11:09 PM
  2. Replies: 15
    Last Post: 10-29-2019, 06:46 AM
  3. [SOLVED] Need help with Indexing/Match the correct value within range/sheets
    By GoranHH in forum Excel General
    Replies: 3
    Last Post: 10-04-2019, 02:20 PM
  4. [SOLVED] Using LARGE or MAX inside INDEX-MATCH formula with multiple criteria
    By Big.Moe in forum Excel Formulas & Functions
    Replies: 8
    Last Post: 02-28-2017, 02:40 AM
  5. Index Match Large formula with multiple criteria
    By Dylan Cooper in forum Excel Formulas & Functions
    Replies: 9
    Last Post: 10-21-2016, 06:00 PM
  6. Replies: 15
    Last Post: 11-25-2014, 08:14 AM
  7. Replies: 1
    Last Post: 10-01-2014, 04:50 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