+ Reply to Thread
Results 1 to 8 of 8

Trying to get the Mode, or Average if there's no MODE in a formula

Hybrid View

  1. #1
    Registered User
    Join Date
    10-07-2016
    Location
    Lincolnshire
    MS-Off Ver
    2010
    Posts
    15

    Trying to get the Mode, or Average if there's no MODE in a formula

    Hi all,

    I've got four cells (A1:D1) where the answer can only 1,2,3 or 4. I have a summary cell (E1) which looks at all four cells and displays an answer. I want it to look at the four cells and tell me the most common number (MODE). If there is no clear MODE (2,2,3,3 or 1,2,3,4) I want it to give me an average number instead. I can get it to do one or the other but struggling to get it to work together.

    I realise that 2,2,3,3 represents a Multi Mode. That is a possible answer so I need to have that in consideration. If th answer is 1,2,3,4 that presents a N/A error which I can get to work but 2,2,3,3 doesn't show an error, it only returns 2.

    Any help would be very much appreciated.

    TiA

    Jack
    Last edited by jackmcguigan1; 10-15-2016 at 06:46 PM.

  2. #2
    Forum Guru
    Join Date
    08-28-2014
    Location
    USA
    MS-Off Ver
    Excel 365 version 2501
    Posts
    18,896

    Re: Trying to get the Mode, or Average if there's no MODE in a formula

    This solution uses four helper cells which could be placed anywhere in row one and could also be hidden for aesthetic purposes. Lets say that you want F1:I1 to be the helper cells. Paste the following formula in F1 and drag across to I1: =COUNTIFS($A1:$D1,A1) The formula that populates the cell which gives the mode or average would then reference the helper cells, like so:
    Formula: copy to clipboard
    =IF(LARGE($F1:$I1,1)=SMALL($F1:$I1,1),AVERAGE(A1:D1),MODE.SNGL(A1:D1))
    Let me know if you have any questions.
    Consider taking the time to add to the reputation of everybody that has taken the time to respond to your query.

  3. #3
    Registered User
    Join Date
    10-07-2016
    Location
    Lincolnshire
    MS-Off Ver
    2010
    Posts
    15

    Re: Trying to get the Mode, or Average if there's no MODE in a formula

    Hi Jete,

    I tried your formula but unfortunately when I get a result of 1,1,2,2 (2,1,2,1 etc) it always shows 1 as the result. I need it to identify that it's a Multi Mode and so Average the values. It should return 1.5

  4. #4
    Forum Guru
    Join Date
    08-28-2014
    Location
    USA
    MS-Off Ver
    Excel 365 version 2501
    Posts
    18,896

    Re: Trying to get the Mode, or Average if there's no MODE in a formula

    Take a look at the attached file.
    Let me know if you have any questions.
    Attached Files Attached Files

  5. #5
    Forum Expert shg's Avatar
    Join Date
    06-20-2007
    Location
    The Great State of Texas
    MS-Off Ver
    2010, 2019
    Posts
    40,689

    Re: Trying to get the Mode, or Average if there's no MODE in a formula

    How about ...

    =CHOOSE(COUNT(MODE.MULT(A1:D1)) + 1, AVERAGE(A1:D1), MODE(A1:D1), AVERAGE(A1:D1))
    Entia non sunt multiplicanda sine necessitate

  6. #6
    Forum Expert shg's Avatar
    Join Date
    06-20-2007
    Location
    The Great State of Texas
    MS-Off Ver
    2010, 2019
    Posts
    40,689

    Re: Trying to get the Mode, or Average if there's no MODE in a formula

    Or ...

    =IF(MOD(COUNT(MODE.MULT(A1:D1)), 2) = 0, AVERAGE(A1:D1), MODE(A1:D1))

  7. #7
    Registered User
    Join Date
    10-07-2016
    Location
    Lincolnshire
    MS-Off Ver
    2010
    Posts
    15

    Re: Trying to get the Mode, or Average if there's no MODE in a formula

    That nailed it shg! Thanks

  8. #8
    Forum Expert shg's Avatar
    Join Date
    06-20-2007
    Location
    The Great State of Texas
    MS-Off Ver
    2010, 2019
    Posts
    40,689

    Re: Trying to get the Mode, or Average if there's no MODE in a formula

    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. [SOLVED] Formula to find the MODE and AVERAGE of Roman Numerals
    By nwb in forum Excel Formulas & Functions
    Replies: 4
    Last Post: 02-27-2014, 03:47 PM
  2. MAX, MIN, MEAN, AVERAGE, MODE for multiple groups...how?
    By || cypher || in forum Excel Formulas & Functions
    Replies: 8
    Last Post: 09-06-2005, 03:05 PM
  3. MAX, MIN, MEAN, AVERAGE, MODE for multiple groups...how?
    By || cypher || in forum Excel Formulas & Functions
    Replies: 0
    Last Post: 09-06-2005, 12:05 PM
  4. MAX, MIN, MEAN, AVERAGE, MODE for multiple groups...how?
    By || cypher || in forum Excel Formulas & Functions
    Replies: 0
    Last Post: 09-06-2005, 10:05 AM
  5. MAX, MIN, MEAN, AVERAGE, MODE for multiple groups...how?
    By || cypher || in forum Excel Formulas & Functions
    Replies: 6
    Last Post: 09-06-2005, 04:05 AM
  6. MAX, MIN, MEAN, AVERAGE, MODE for multiple groups...how?
    By || cypher || in forum Excel Formulas & Functions
    Replies: 0
    Last Post: 09-06-2005, 12:05 AM
  7. MAX, MIN, MEAN, AVERAGE, MODE for multiple groups...how?
    By || cypher || in forum Excel Formulas & Functions
    Replies: 0
    Last Post: 09-05-2005, 11:05 PM
  8. MAX, MIN, MEAN, AVERAGE, MODE for multiple groups...how?
    By || cypher || in forum Excel Formulas & Functions
    Replies: 2
    Last Post: 07-14-2005, 02:05 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