Summary

To filter data arranged horizontally in columns, you can use the FILTER function.  In the example shown, the formula in C9 is:

=TRANSPOSE(FILTER(data,group="fox"))

where data (C4:L6) and group (C5:L5) are named ranges.

Generic formula

=FILTER(data,logic)

Explanation 

Note: FILTER is a new dynamic array function in Excel 365. In other versions of Excel, there are alternatives, but they are more complex.

There are ten columns of data in the range C4:L6. The goal is to filter this horizontal data and extract only columns (records) where the group is "fox". For convenience and readability, the worksheet contains three named rangesdata (C4:L6) and group (C5:L5), and age (C6:L6).

The FILTER function can be used to extract data arranged vertically (in rows) or horizontally (in columns). FILTER will return the matching data in the same orientation.  No special setup is required. In the example shown, the formula in C9 is:

=FILTER(data,group="fox")

Working from the inside out, the include argument for FILTER is a logical expression:

group="fox" // test for "fox"

When the logical expression is evaluated, it returns an array of 10 TRUE and FALSE values:

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

Note: the commas (,) in this array indicate columns. Semicolons (;) would indicate rows.

The array contains one value per column in the data, and each TRUE corresponds to a column where the group is "fox". This array is returned directly to FILTER as the include argument, and it performs the actual filtering:

FILTER(data,{TRUE,FALSE,TRUE,FALSE,FALSE,TRUE,TRUE,TRUE,TRUE,FALSE})

Only data that corresponds to TRUE values passes the filter, so FILTER returns the 6 columns where the group is "fox". FILTER returns this data in the original horizontal structure. Because FILTER is a dynamic array function, the results spill into the range C9:H11.

This is a dynamic solution – if any source data in C4:L6 changes, the results from FILTER automatically update.

Transpose to vertical format

To transpose the results from FILTER into a vertical (rows) format, you can wrap the TRANSPOSE function around the FILTER function like this:

=TRANSPOSE(FILTER(data,group="fox"))

The result looks like this:

FILTER and TRANSPOSE horizontal data

This formula is explained in more detail here.

Filter on age

The same basic formula can be used to filter the data in different ways. For example, to filter data to show only columns where age is less than 22, you can use a formula like this:

=FILTER(data,age<22)

FILTER returns the four matching columns of data:

FILTER columns by age < 22

Dynamic Array Formulas are available in Office 365 only.
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.