Summary

To filter columns, supply a horizontal array for the include argument. In the example shown, the formula in I5 is:

=FILTER(B5:G12,(B4:G4="a")+(B4:G4="c")+(B4:G4="e"))

The result is a filtered set of data that contains only columns A, C, and E from the source data.

Generic formula

=FILTER(data,(header="a")+(header="b"))

Explanation 

Although FILTER is more commonly used to filter rows, you can also filter columns, the trick is to supply an array with the same number of columns as the source data. In this example, we construct the array we need with boolean logic, also called Boolean algebra.

In Boolean algebra, multiplication corresponds to AND logic, and addition corresponds to OR logic. In the example shown, we are using Boolean algebra with OR logic (addition) to target only the columns A, C, and E like this:

(B4:G4="a")+(B4:G4="c")+(B4:G4="e")

After each expression is evaluated, we have three arrays of TRUE/FALSE values:

{TRUE,FALSE,FALSE,FALSE,FALSE,FALSE}+
{FALSE,FALSE,TRUE,FALSE,FALSE,FALSE}+
{FALSE,FALSE,FALSE,FALSE,TRUE,FALSE}

The math operation (addition) converts the TRUE and FALSE values to 1s and 0s, so you can think of the operation like this:

{1,0,0,0,0,0}+
{0,0,1,0,0,0}+
{0,0,0,0,1,0}

In the end, we have a single horizontal array of 1s and 0s:

{1,0,1,0,1,0}

which is delivered directly to the FILTER function as the include argument:

=FILTER(B5:G12,{1,0,1,0,1,0})

Notice there are 6 columns in the source data and 6 values in the array, all either 1 or 0. FILTER uses this array as a filter to include only columns 1, 3, and 5 from the source data. Columns 2, 4, and 6 are removed. In other words, the only columns that survive are associated with 1s.

With the MATCH function

Applying OR logic with addition as shown above works fine, but it doesn't scale well, and makes it impossible to use a range of values from a worksheet as criteria. As an alternative, you can use the MATCH function together with the ISNUMBER function like this to construct the include argument more efficiently:

=FILTER(B5:G12,ISNUMBER(MATCH(B4:G4,{"a","c","e"},0)))

The MATCH function is configured to look for all column headers in the array constant {"a","c","e"} as shown. We do it this way so that the result from MATCH has dimensions compatible with the source data, which contains 6 columns. Notice also that the third argument in MATCH is set as zero to force an exact match.

After MATCH runs, it returns an array like this:

{1,#N/A,2,#N/A,3,#N/A}

This array goes directly into ISNUMBER, which returns another array:

{TRUE,FALSE,TRUE,FALSE,TRUE,FALSE}

As above, this array is horizontal and contains 6 values separated by commas. FILTER uses the array to remove columns 2, 4, and 6.

With a range

Since the column headers are already on the worksheet in the range I4:K4, the formula above can easily be adapted to use the range directly like this:

=FILTER(B5:G12,ISNUMBER(MATCH(B4:G4,I4:K4,0)))

The range I4:K4 is evaluated as {"a","c","e"}, and behaves just like the array constant in the formula above.

Dave Bruns Profile Picture

AuthorMicrosoft Most Valuable Professional Award

Dave Bruns

Hi - I'm Dave Bruns, and I run Exceljet with my wife, Lisa. Our goal is to help you work faster in Excel. We create short videos, and clear examples of formulas, functions, pivot tables, conditional formatting, and charts.