Exceljet

Quick, clean, and to the point

Filter values in array formula

Excel formula: Filter values in array formula
Generic formula 
{=IF(ISNUMBER(MATCH(data,filter,0)),data)}
Explanation 

To filter a data in an array formula (to exclude or require certain values), you can use an array formula based on the IF, MATCH, and ISNUMBER functions.

In the example shown, the formula in H5:

{=COUNT(IF(ISNUMBER(MATCH(data,filter,0)),data))}

where "data" is the named range B4:D11 and "filter" is the named range F4:F6.

Note: this is an array formula and must be entered with control + shift + enter.

How this formula works

  1. The MATCH function checks all values in the named range "data" against values in "filter"
  2. ISNUMBER converts matched values to TRUE and non-matched values to FALSE
  3. IF uses the array output in #2 above to filter values, excluding values in "filter"

The final array looks like this:

{1,FALSE,3;FALSE,4,FALSE;FALSE,FALSE,FALSE;1,FALSE,3;FALSE,FALSE,FALSE;3,FALSE,FALSE;FALSE,4,FALSE;FALSE,FALSE,4}

COUNT is only used to verify the result.

Filter to exclude

In cell H6 the formula has been modified to exclude values using 1-ISNUMBER like so:

=COUNT(IF(1-ISNUMBER(MATCH(data,filter,0)),data))

This effectively reverses the array output in step #2 above.

Author 
Dave Bruns

Excel Formula Training

Formulas are the key to getting things done in Excel. In this accelerated training, you'll learn how to use formulas to manipulate text, work with dates and times, lookup values with VLOOKUP and INDEX & MATCH, count and sum with criteria, dynamically rank values, and create dynamic ranges. You'll also learn how to troubleshoot, trace errors, and fix problems. Instant access. See details here.