+ Reply to Thread
Results 1 to 11 of 11

IF, COUNTIF, AVG, MIN/MAX all in one!

  1. #1
    Forum Contributor
    Join Date
    07-22-2013
    Location
    Phoenix, AZ
    MS-Off Ver
    Excel 2010
    Posts
    100

    IF, COUNTIF, AVG, MIN/MAX all in one!

    Okay... In Column O Row 5 through 19...

    I need a formula in Column O Row 20 that states:

    IF the rows 5:19 have a count that is greater than >=5 then AVG those rows (minus the MAX and MIN #) if the count is <5 then average the rows.
    AND I only want it to average the numbers that are not blank!

    Please help.
    Last edited by mphillips; 09-09-2014 at 11:42 PM.

  2. #2
    Forum Expert
    Join Date
    03-28-2014
    Location
    Hyderabad,India
    MS-Off Ver
    Excel 2013
    Posts
    1,887

    Re: IF, COUNTIF, AVG, MIN/MAX all in one!

    Hi,

    It is all ways difficult to assume data.

    I hope this will help you,

    Punnam
    Attached Files Attached Files

  3. #3
    Administrator FDibbins's Avatar
    Join Date
    12-29-2011
    Location
    Duncansville, PA USA
    MS-Off Ver
    Excel 7/10/13/16/365 (PC ver 2310)
    Posts
    52,956

    Re: IF, COUNTIF, AVG, MIN/MAX all in one!

    Try this...
    =IF(COUNT($O$5:$O$19)>5,AVERAGEIFS($O$5:$O$19,$O$5:$O$19,"<"&MAX($O$5:$O$19),$O$5:$O$19,">"&MIN($O$5:$O$19)),AVERAGE($O$5:$O$19))

    average excludes blanks by default
    1. Use code tags for VBA. [code] Your Code [/code] (or use the # button)
    2. If your question is resolved, mark it SOLVED using the thread tools
    3. Click on the star if you think someone helped you

    Regards
    Ford

  4. #4
    Forum Contributor
    Join Date
    07-22-2013
    Location
    Phoenix, AZ
    MS-Off Ver
    Excel 2010
    Posts
    100

    Re: IF, COUNTIF, AVG, MIN/MAX all in one!

    I've attached an example of the data and the answer I am looking for as for some reason the two formulas that are above do not seem to be returning what I'm hoping it will.
    Attached Files Attached Files

  5. #5
    Administrator FDibbins's Avatar
    Join Date
    12-29-2011
    Location
    Duncansville, PA USA
    MS-Off Ver
    Excel 7/10/13/16/365 (PC ver 2310)
    Posts
    52,956

    Re: IF, COUNTIF, AVG, MIN/MAX all in one!

    OK you said blank. 0 is not blank

    Try this ARRAY formula...
    =IF(COUNTIF(C3:C17,">0")>=5,AVERAGEIFS(C3:C17,C3:C17,"<>0",C3:C17,"<"&MAX(C3:C17),C3:C17,">"&SMALL(IF(C3:C18<>0,C3:C18),1)),AVERAGEIF(C3:C17,">0"))

    ...confirmed by pressing CTRL+SHIFT+ENTER to activate the array, not just ENTER. You will know the array is active when you see curly braces { } appear around your formula. If you do not CTRL+SHIFT+ENTER you will get an error or a clearly incorrect answer. Press F2 on that cell and try again.

  6. #6
    Forum Contributor
    Join Date
    07-22-2013
    Location
    Phoenix, AZ
    MS-Off Ver
    Excel 2010
    Posts
    100

    Re: IF, COUNTIF, AVG, MIN/MAX all in one!

    That works great if the count is less than five, but I'm getting the #DIV/0 error if there are more than 5, with the removal of the MIN/MAX.

  7. #7
    Forum Expert
    Join Date
    03-28-2014
    Location
    Hyderabad,India
    MS-Off Ver
    Excel 2013
    Posts
    1,887

    Re: IF, COUNTIF, AVG, MIN/MAX all in one!

    HI,

    Check this i guess u r requirement is not at clear ,

    1) Do u have have "0" values all time the column
    2) Count >5 , should include "Zero" Values

    Punnam
    Attached Files Attached Files

  8. #8
    Administrator FDibbins's Avatar
    Join Date
    12-29-2011
    Location
    Duncansville, PA USA
    MS-Off Ver
    Excel 7/10/13/16/365 (PC ver 2310)
    Posts
    52,956

    Re: IF, COUNTIF, AVG, MIN/MAX all in one!

    OK, Im not seeing that error. Take a look at the attached, my formula is in yellow, and I added another example with 6 values.

    Did you use CTRL SHFT ENTER to enter it?
    Attached Files Attached Files

  9. #9
    Forum Expert
    Join Date
    03-28-2014
    Location
    Hyderabad,India
    MS-Off Ver
    Excel 2013
    Posts
    1,887

    Re: IF, COUNTIF, AVG, MIN/MAX all in one!

    Check this
    =IF((COUNTIF(G3:G17,">"&0))>=5,AVERAGEIFS(G3:G17,G3:G17,"<"&MAX(G3:G17),G3:G17,">"&SMALL((G3:G17),COUNTIF(G3:G17,0)+1)),AVERAGEIFS(G3:G17,G3:G17,"<>"&0))

    Punnam

  10. #10
    Forum Contributor
    Join Date
    07-22-2013
    Location
    Phoenix, AZ
    MS-Off Ver
    Excel 2010
    Posts
    100

    Re: IF, COUNTIF, AVG, MIN/MAX all in one!

    The Example (17) worked perfectly, once I changed the 0's to be blank. Thank you all so much for your help!

  11. #11
    Administrator FDibbins's Avatar
    Join Date
    12-29-2011
    Location
    Duncansville, PA USA
    MS-Off Ver
    Excel 7/10/13/16/365 (PC ver 2310)
    Posts
    52,956

    Re: IF, COUNTIF, AVG, MIN/MAX all in one!

    Based on your last post it seems that you are satisfied with the solution(s) you've received but you haven't marked your thread as SOLVED. If your problem has not been solved you can use Thread Tools (located above your first post) and choose "Mark this thread as unsolved".
    Thanks.

    Also, as a relatively new member of the forum, you may not be aware that you can thank those who have helped you by clicking the small star icon 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 those who helped.

+ 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] =Subtotal(countif,Range); Subtotal and countif in 1 formula [SOLVED]
    By thomas.mapua in forum Excel General
    Replies: 5
    Last Post: 01-06-2012, 11:33 AM
  2. Combining a Date Range COUNTIF and a general COUNTIF
    By jacobtom in forum Excel General
    Replies: 1
    Last Post: 09-15-2011, 05:06 PM
  3. Adding a CountIF to a formula that is already Countif
    By Cmorgan in forum Excel General
    Replies: 4
    Last Post: 06-01-2011, 09:34 AM
  4. [SOLVED] COUNTIF or not to COUNTIF on a range in another sheet
    By Ellie in forum Excel Formulas & Functions
    Replies: 4
    Last Post: 09-15-2005, 05:06 PM
  5. Countif w/ Multiple Criteria-How do I use countif
    By Patrick_KC in forum Excel Formulas & Functions
    Replies: 2
    Last Post: 08-09-2005, 05: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