+ Reply to Thread
Results 1 to 8 of 8

Return the Top value from a Filtered array based on multiple criteria (no helper columns)

  1. #1
    Registered User
    Join Date
    10-17-2023
    Location
    Cincinnati, OH
    MS-Off Ver
    MS 365 Version 2310
    Posts
    16

    Return the Top value from a Filtered array based on multiple criteria (no helper columns)

    Hi all,

    I am probably a 3/10 on the Excel literacy scale, and I come looking for guidance from the maestros.

    I have some customer data, and I want to return the top purchased product for each individual customer.

    Data

    Customer Product Purchased Revenue
    Customer A Blue 5
    Customer B Red 1
    Customer C Red 1
    Customer A Blue 5
    Customer B Red 1
    Customer C Green 2
    Customer A Orange 20
    Customer B Red 1
    Customer C Blue 1
    Customer A Blue 15
    Customer B Red 2
    Customer C Gray 2


    So, if I have a cell with text Customer A, I would like to have Blue returned in the adjacent cell, since Blue has a net revenue of $25 (greater than Orange at $20)

    I know how to do this using helper tables, so I am looking for the coveted SINGLE FORMULA solution.

    Excel forum Help.xlsx

    Thanks!
    John

  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,848

    Re: Return the Top value from a Filtered array based on multiple criteria (no helper colum

    Administrative Note:

    Welcome to the forum.

    Is your forum profile showing the Excel PRODUCT that you need this to work for?

    Members will tailor the solutions they offer to the Office PRODUCT (Excel, NOT Windows) that you have. Please check that your forum profile is up-to-date in this respect. If you aren't sure, in Excel go to File | Account and report what it says below the MS logo at the top of that page. If your product is for Mac, please also state this.

    The three most recent Excel products are Excel 2019, Excel 2021 and MS365 - if you are using MS365, please give this name along with the version number in your profile (e.g. MS365 Version 2306). This is in the About Excel section further down the Account page.

    Thanks.
    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 Guru
    Join Date
    09-10-2017
    Location
    Chippenham, England
    MS-Off Ver
    365
    Posts
    15,080

    Re: Return the Top value from a Filtered array based on multiple criteria (no helper colum

    How about
    Formula: copy to clipboard
    Please Login or Register  to view this content.

  4. #4
    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,848

    Re: Return the Top value from a Filtered array based on multiple criteria (no helper colum

    Try this:

    =LET(c,E3:E14,p,F3:F14,n,COUNTIFS(E3:E14,c,F3:F14,p),s,SORTBY(HSTACK(E3:F14,n),n,-1),TAKE(DROP(FILTER(s,INDEX(s,,1)=B2),,1),1,1))

  5. #5
    Registered User
    Join Date
    10-17-2023
    Location
    Cincinnati, OH
    MS-Off Ver
    MS 365 Version 2310
    Posts
    16

    Re: Return the Top value from a Filtered array based on multiple criteria (no helper colum

    This did the trick! Nice job.... no idea what the formula means, but I will learn eventually...

    Thanks for the help!

  6. #6
    Registered User
    Join Date
    10-17-2023
    Location
    Cincinnati, OH
    MS-Off Ver
    MS 365 Version 2310
    Posts
    16

    Re: Return the Top value from a Filtered array based on multiple criteria (no helper colum

    This one was close, but it actually was returning the product that appeared the most, rather than the product with the most revenue.

    Thanks for the help!

  7. #7
    Forum Guru
    Join Date
    09-10-2017
    Location
    Chippenham, England
    MS-Off Ver
    365
    Posts
    15,080

    Re: Return the Top value from a Filtered array based on multiple criteria (no helper colum

    Glad to help & thanks for the feedback.

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

    Re: Return the Top value from a Filtered array based on multiple criteria (no helper colum

    Quote Originally Posted by jdenoma View Post
    This one was close, but it actually was returning the product that appeared the most, rather than the product with the most revenue.

    Thanks for the help!
    Are you talking to me? If so, then it returns Blue, which is what you said you wanted.

    Maybe you mean this?

    =LET(c,E3:E14,p,F3:F14,n,SUMIFS(G3:G14,E3:E14,c,F3:F14,p),s,SORTBY(HSTACK(E3:F14,n),n,-1),TAKE(DROP(FILTER(s,INDEX(s,,1)=B2),,1),1,1))

    Glad to have helped.

    If you have not already done so, you may not be aware that you can thank 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.
    Last edited by AliGW; 11-02-2023 at 03:18 AM.

+ 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: 1
    Last Post: 06-01-2022, 01:59 AM
  2. [SOLVED] Return most recent occurrence in list based on multiple array criteria
    By Marbleking in forum Excel Formulas & Functions
    Replies: 12
    Last Post: 09-05-2020, 03:37 PM
  3. Replies: 2
    Last Post: 08-13-2018, 09:43 PM
  4. [SOLVED] match() an array filtered based on criteria in another column
    By simarui in forum Excel Formulas & Functions
    Replies: 2
    Last Post: 11-11-2014, 03:32 PM
  5. Array formula to return multiple values based on various (OR) criteria
    By dancing-shadow in forum Excel Formulas & Functions
    Replies: 4
    Last Post: 12-20-2013, 05:12 AM
  6. Return array based on multiple criteria
    By kmacd in forum Excel General
    Replies: 3
    Last Post: 01-05-2011, 09:05 PM
  7. Return value based on certain criteria in multiple columns
    By kilaalaa in forum Excel Programming / VBA / Macros
    Replies: 0
    Last Post: 11-03-2005, 11:51 AM

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