Excel 365’s FILTER() function is great for getting a cut of data that meets your criteria. But what if you need to filter and then show non-adjacent columns? Something like below. In this article, let me show you a few options to get discrete columns after filtering with the FILTER function.

Using CHOOSECOLS with FILTER()
Imagine you have a table data named “staff” and you want to see all the staff who joined in year 2021. We can use below FILTER function for that.
=FILTER(staff, YEAR(staff[date of join])=2021)
This will provide a list of all staff who joined in year 2021, as depicted below.

But we don’t want all columns, just ID, Gender, Salary and Leave Balance.
To see just columns 1,2,7 & 8 of this filtered data, we can use below formula.
=CHOOSECOLS(
FILTER(staff, YEAR(staff[date of join])=2021),
1,2,7,8)
This will give you exactly what you need without anything else.

What if I need to get data, but the column order is different from original data…

Say, you do want the columns 2,6,8&9 but you want them to show up in the order 6,8,2&9 in the final output.
You can still use the CHOOSECOLS function like below.
=CHOOSECOLS(
FILTER(staff, YEAR(staff[date of join])=2021),
6,8,2,9)
How to get columns from a list of header names
If you want to use a range of column names and show filtered data for only those columns, we can use XMATCH along with CHOOSECOLS and FILTER, as demoed below.

- Set up your column headers in a range like Z5:AC5
- Now, we can use XMATCH to find the positions of these headers. =XMATCH(Z5:AC5, staff[#headers])
- When you pass the result of XMATCH to CHOOSECOLS, you can pick these columns.
=CHOOSECOLS(
FILTER(staff,YEAR(staff[Date of Join])=2021),
XMATCH(Z5:AC5,staff[#Headers]))
How does this work…
- Let’s go inside out.
- The FILTER() function gets all the staff data for people whose joining date is in 2021.
- Range Z5:AC5 holds the names of the columns we want to see.
- XMATCH(Z5:AC5, staff[#Headers]) will tell you the column numbers for the columns you want by looking them up in the table header row.
- CHOOSECOLS() will then return those exact columns













11 Responses to “Who is the most consistent seller? [BYOD]”
The Date column in the sample file is Text not Dates
[…] http://chandoo.org/wp/2015/02/18/calculating-consistency-in-excel/?utm_source=feedburner&utm_med… […]
Great Chandoo. Keep it up, Looking forward more from BYOD..
Thanks
With Excel 2013 the pivot table could be connected to the data model which provides a distinct count.
This will do for invoice count
=COUNTIF(F:F,H12)
Instead of
=COUNTIFS(sales[SELLER],$H12)
Excellent document. How did you make the last graphic? Witch app. Thanks for answer.
Can someone tell me what =countif(sales[date],sales[date]) is counting? The value is 19. Its found in the =SUMPRODUCT(IF(sales[SELLER]=H12,1/COUNTIFS(sales[SELLER],H12,sales[date],sales[date]),0))
Hi Chris,
=countif(sales [date],sales[date]) function is counting the unique dates in the table.
Vândalo
Excellent document!
Can you explain more about the calculation on Weighted consistency? More specific the small number is 0,00001 ?
How come the number should be smaller if there is more sellers?
Hi,
Not understood this formula: {=SUMPRODUCT(IF(sales[SELLER]=H12,1/COUNTIFS(sales[SELLER],H12,sales[date],sales[date]),0))}
Please explain.
Thanks.