+ Reply to Thread
Results 1 to 6 of 6

Median IF ignoring errors

  1. #1
    Registered User
    Join Date
    01-12-2016
    Location
    New York
    MS-Off Ver
    2015
    Posts
    76

    Median IF ignoring errors

    How do I write the formula for Median IF, while also ignoring errors?

    Looking to find the median price of all the Red sweaters while also ignoring any errors.....

  2. #2
    Forum Expert CK76's Avatar
    Join Date
    06-16-2015
    Location
    ONT, Canada
    MS-Off Ver
    MS365 Apps for enterprise
    Posts
    5,902

    Re: Median IF ignoring errors

    Something like...

    =MEDIAN(IF((CriteriaRange="Criteria")*NOT(ISERR(ValueRange)),ValueRange))
    Confirmed as array (CTRL + SHIFT + ENTER)

    Edit: But the best practice is to get rid of error in the source calculation (if the error stems from it) by using IFERROR().
    ?Progress isn't made by early risers. It's made by lazy men trying to find easier ways to do something.?
    ― Robert A. Heinlein

  3. #3
    Registered User
    Join Date
    01-12-2016
    Location
    New York
    MS-Off Ver
    2015
    Posts
    76

    Re: Median IF ignoring errors

    Unfortunately that doesn't work; any other suggestions?

  4. #4
    Forum Expert CK76's Avatar
    Join Date
    06-16-2015
    Location
    ONT, Canada
    MS-Off Ver
    MS365 Apps for enterprise
    Posts
    5,902

    Re: Median IF ignoring errors

    Without seeing how your data is set up. Can't really give you other suggestions.

    I'd recommend uploading sample workbook with desensitized data along with expected result.

    To upload, use "Go Advanced" Button and find "Manage Attachments" hyperlink. It will launch new window/tab for managing uploads.

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

    Re: Median IF ignoring errors

    Use this array formula:

    =MEDIAN(IF($B$1:$B$10="B",IF(NOT(ISERROR($A$1:$A$10)),$A$1:$A$10)))

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

    As you can see, it does work. D+SO, if it's not working on your sheet, we will need to see a sample. In which case:

    Will you please attach a SMALL sample Excel workbook (10-20 rows of data is usually enough)? However, please give us an indication of the approximate number of rows of data you want the solution to work with (100, 1000, 100,000 or whatever). Please don't attach a picture of an Excel sheet (no-one will want to re-type all your stuff before starting).

    1. Make sure that your sample data are truly REPRESENTATIVE of your real data. The use of unrepresentative data is very frustrating and can lead to long delays in reaching a solution.

    2. Make sure that your desired solution is also shown (mock up the results manually).

    3. Make sure that all confidential information is removed first!!

    4. Try to avoid using merged cells. They cause lots of problems!

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

  6. #6
    Forum Moderator
    Join Date
    01-21-2014
    Location
    St. Joseph, Illinois U.S.A.
    MS-Off Ver
    Office 365 v 2404
    Posts
    13,406

    Re: Median IF ignoring errors

    If I understand correctly something like this?
    Formula: copy to clipboard
    Please Login or Register  to view this content.
    It doesn't have to be array entered and it ignores errors (option 6).
    Dave

+ 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] Median function ignoring zero
    By robin5 in forum Excel Formulas & Functions
    Replies: 12
    Last Post: 01-12-2016, 11:11 PM
  2. [SOLVED] Ignoring errors
    By Cmorgan in forum Excel - New Users/Basics
    Replies: 3
    Last Post: 05-16-2013, 05:05 AM
  3. [SOLVED] Formula to get the median, but ignoring the duplicate numbers in the column
    By Rianne in forum Excel Formulas & Functions
    Replies: 4
    Last Post: 01-16-2013, 03:23 AM
  4. Ignoring Duplicates when Calculating a Median
    By trfarley05 in forum Excel General
    Replies: 3
    Last Post: 06-08-2012, 09:42 AM
  5. Median if - ignoring zeros
    By adame in forum Excel General
    Replies: 1
    Last Post: 05-24-2012, 11:57 AM
  6. Ignoring errors
    By Cmorgan in forum Excel - New Users/Basics
    Replies: 2
    Last Post: 12-23-2011, 09:12 AM
  7. Median ignoring Zero Values
    By tlosgyl3 in forum Excel Formulas & Functions
    Replies: 4
    Last Post: 10-13-2005, 04:14 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