+ Reply to Thread
Results 1 to 9 of 9

Auto Populate the Nth Large Value

  1. #1
    Forum Contributor
    Join Date
    02-27-2015
    Location
    United Arab Emirates
    MS-Off Ver
    2013
    Posts
    162

    Exclamation Auto Populate the Nth Large Value

    Dear Expert,

    I need to find the Top nth value from a set of data by combining with 2 criteria.

    Please find attached sheet with example.
    Attached Files Attached Files
    Last edited by fareedexcel; 10-16-2017 at 07:07 AM. Reason: Attachment missing
    Regards,

    Fareed

  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
    43,996

    Re: Auto Populate the Nth Large Value

    No attachment.

    Unfortunately the attachment icon doesn't work at the moment. So, to attach an Excel file you have to do the following: Just before posting, scroll down to Go Advanced and then scroll down to Manage Attachments. Now follow the instructions at the top of that screen.
    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
    Forum Contributor
    Join Date
    02-27-2015
    Location
    United Arab Emirates
    MS-Off Ver
    2013
    Posts
    162

    Re: Auto Populate the Nth Large Value

    Attached file as per your Instructions

  4. #4
    Forum Contributor
    Join Date
    02-27-2015
    Location
    United Arab Emirates
    MS-Off Ver
    2013
    Posts
    162

    Re: Auto Populate the Nth Large Value

    Quote Originally Posted by Glenn Kennedy View Post
    No attachment.

    Unfortunately the attachment icon doesn't work at the moment. So, to attach an Excel file you have to do the following: Just before posting, scroll down to Go Advanced and then scroll down to Manage Attachments. Now follow the instructions at the top of that screen.
    Please unlock my Post. Sheet atatched.

  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
    43,996

    Re: Auto Populate the Nth Large Value

    Unlock you post??? I never locked it !!

    This is a first step. Please take a look at it.

    In D9, copied down:
    =IF(ROWS($1:1)<=D$5,ROWS($1:1),"")

    In E9, an array formula, copied across and down:
    Formula: copy to clipboard
    Please Login or Register  to view this content.


    Array Formulae are a little different from ordinary formulae in that they MUST be confirmed in the FIRST CELL ONLY by pressing CTRL+SHIFT+ENTER to activate the array, not just ENTER. After that, the array can be dragged down as normal, to cover the desired range.

    You will know the array is active when you see curly brackets { } - or "curly braces" for those of you in the USA, or "flower brackets" for those of you in India - appear around the outside of your formula. If you do not use 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 brackets yourself - it won't work...

    How likely is it that there will be ties for the total amount? If this is a possibility, I will need to do a bit more work on this.
    Attached Files Attached Files

  6. #6
    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
    43,996

    Re: Auto Populate the Nth Large Value

    I did the extra bit. Take a look at rows 2&3 of MASTER of ORIGINAL.xlsx. Ihave introduced a tie. Now look at Rows 9 & 10 of working. It gives the incorrect answer for one of the tied results. Now look at MODIFIED.xlsx. the same tie is there, but now the correct result is returned.

    Array formula in E9 is now:
    Formula: copy to clipboard
    Please Login or Register  to view this content.
    Attached Files Attached Files

  7. #7
    Forum Contributor
    Join Date
    02-27-2015
    Location
    United Arab Emirates
    MS-Off Ver
    2013
    Posts
    162

    Re: Auto Populate the Nth Large Value

    Quote Originally Posted by Glenn Kennedy View Post
    I did the extra bit. Take a look at rows 2&3 of MASTER of ORIGINAL.xlsx. Ihave introduced a tie. Now look at Rows 9 & 10 of working. It gives the incorrect answer for one of the tied results. Now look at MODIFIED.xlsx. the same tie is there, but now the correct result is returned.

    Array formula in E9 is now:
    Formula: copy to clipboard
    Please Login or Register  to view this content.
    Thanks Expert for the solution. The result is coming perfectly. If you have some time can you please share on the formula logic on getting the result. I'm sorry if i'm wasting your time.

  8. #8
    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
    43,996

    Re: Auto Populate the Nth Large Value

    =IFERROR(INDEX(Master!A$2:A$8000,- tells Excel where to look for the results

    MATCH( - where there is a match between

    LARGE( - the largest value matching BOTH of the criteria

    IF(IF($D$3="All",TRUE,Master!$D$2:$D$8000=Working!$D$3), first criterion : company name = selected name. This bit returns TRUE or FALSE. An extra term was added to retun TRUE if "All" was selected

    IF(IF($D$4="All",TRUE,Master!$E$2:$E$8000=$D$4), - second criterion - similar to first criterion

    Master!$P$2:$P$8000+ROW(Master!$P$2:$P$8000)/10^10)), return the largest value... but add on a very small number (the row number divided by 10 to the power of 10) to make each total completely unique.

    Working!$D9), when this is 1, it returns the first largest, 2 it returns the second largest, etc.

    So at this point we have say....40,000.000013 (made up number) being the nth largest value. we now need to find out what row it's on. So we need to match it with the column of totals... which also need to have the tiny amount added on.

    Master!$P$2:$P$8000+ROW(Master!$P$2:$P$8000)/10^10,0)),"") - so that's what happens here

    That's basically it.

  9. #9
    Forum Contributor
    Join Date
    02-27-2015
    Location
    United Arab Emirates
    MS-Off Ver
    2013
    Posts
    162

    Re: Auto Populate the Nth Large Value

    Thanks for your guidance. Much appreciated. I'm marking this thread as solved

+ 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. Replies: 5
    Last Post: 06-05-2016, 11:32 AM
  2. [SOLVED] Auto Populate cell based on auto filter selection from table in same sheet
    By missydanni in forum Excel Formulas & Functions
    Replies: 1
    Last Post: 12-02-2013, 05:03 PM
  3. Auto-populate from other sheets in a master, than auto total duplicates
    By Melyd in forum Excel Programming / VBA / Macros
    Replies: 6
    Last Post: 08-30-2013, 01:48 PM
  4. Replies: 2
    Last Post: 07-31-2013, 02:00 PM
  5. Replies: 3
    Last Post: 03-13-2012, 03:16 PM
  6. Replies: 3
    Last Post: 02-28-2012, 11:54 AM
  7. Populate large sheet using VBA
    By luis33 in forum Excel Programming / VBA / Macros
    Replies: 3
    Last Post: 04-12-2011, 11:35 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