+ Reply to Thread
Results 1 to 5 of 5

Total the highest 4 values over multiple columns

  1. #1
    Registered User
    Join Date
    01-17-2007
    Location
    Downunder NZ
    MS-Off Ver
    MS Office 365
    Posts
    82

    Total the highest 4 values over multiple columns

    I would to get the sum of the highest 4 values over 8 columns

    total in E8 and the values are in H8 = 150, J8 = 76, L8 = 86, N8 = 73, P8 = 100, R8 = 98, T8 = 86, V8 = 98, X8 = 68 and Z8 = 100.

    How can you sort out when there are 2 or more of the lower of the 4 highest are the same?

    Thanks in advance.
    Attached Files Attached Files
    Last edited by AliGW; 10-23-2018 at 02:55 AM. Reason: Typo in thread title fixed.

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

    Re: Totally the highest 4 values over multiply columns

    One way:

    =SUM(LARGE(H8:Z8,{1,2,3,4}))

    what do you mean by: "How can you sort out when there are 2 or more of the lower of the 4 highest are the same?"???
    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
    01-17-2007
    Location
    Downunder NZ
    MS-Off Ver
    MS Office 365
    Posts
    82

    Re: Totally the highest 4 values over multiply columns

    Glenn thanks for the speedy reply.

    There are other numbers in the other columns I only want the named column values to be totalled.

    In the example the H8, P8, Z8 are be used but R8 & V8 have the same value of 98 so only one of these can be used to make up the total required.

    I hope that explains it better.

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

    Re: Total the highest 4 values over multiple columns

    The most important detail left out!!

    an array formula:
    =SUMPRODUCT(LARGE(IF(MOD(COLUMN($H$8:$Z$8)-COLUMN($H$8),2)=0,($H$8:$Z$8),0),{1,2,3,4}))

    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...

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

    Re: Totally the highest 4 values over multiply columns

    or:

    =SUM(LARGE(IF(MOD(COLUMN($H$8:$Z$8)-COLUMN($H$8),2)=0,($H$8:$Z$8),0),{1,2,3,4}))

    also array entered.

+ 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. Filter highest values of columns
    By neil40 in forum Excel Charting & Pivots
    Replies: 3
    Last Post: 04-26-2018, 05:15 PM
  2. Replies: 3
    Last Post: 06-09-2016, 12:51 PM
  3. Replies: 4
    Last Post: 12-18-2014, 12:55 PM
  4. Multiply and sum values across columns based on delimited string
    By Pen+Paper in forum Excel Formulas & Functions
    Replies: 2
    Last Post: 09-10-2014, 04:06 PM
  5. [SOLVED] How to multiply values of all numbers in spreadsheet rows and columns?
    By havenoideawhattodo in forum Excel General
    Replies: 2
    Last Post: 08-06-2014, 05:29 AM
  6. Formula To Add Highest Two Values In Columns
    By alcatraz99 in forum Excel Formulas & Functions
    Replies: 3
    Last Post: 05-20-2013, 01:41 PM
  7. Getting the highest values from excel columns
    By chembee in forum Excel General
    Replies: 4
    Last Post: 07-30-2012, 01:03 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