How to get non-adjacent columns with FILTER function in Excel

Share

Facebook
Twitter
LinkedIn

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.

Get Non-adjacent columns with Excel 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.

This will provide a list of all staff who joined in year 2021, as depicted below.

filter result, but we don't want all the columns - just 1,2,7 & 8

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.

This will give you exactly what you need without anything else.

Filter with choosecols - sample result

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

Showing columns out of order in Excel

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.

using column headers to figure out which columns to show
  1. Set up your column headers in a range like Z5:AC5
  2. Now, we can use XMATCH to find the positions of these headers. =XMATCH(Z5:AC5, staff[#headers])
  3. 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

Learn more about these functions:

Facebook
Twitter
LinkedIn

Share this tip with your colleagues

Excel and Power BI tips - Chandoo.org Newsletter

Get FREE Excel + Power BI Tips

Simple, fun and useful emails, once per week.

Learn & be awesome.

Welcome to Chandoo.org

Thank you so much for visiting. My aim is to make you awesome in Excel & Power BI. I do this by sharing videos, tips, examples and downloads on this website. There are more than 1,000 pages with all things Excel, Power BI, Dashboards & VBA here. Go ahead and spend few minutes to be AWESOME.

Read my storyFREE Excel tips book

Overall I learned a lot and I thought you did a great job of explaining how to do things. This will definitely elevate my reporting in the future.
Rebekah S
Reporting Analyst
Excel formula list - 100+ examples and howto guide for you

From simple to complex, there is a formula for every occasion. Check out the list now.

Calendars, invoices, trackers and much more. All free, fun and fantastic.

Advanced Pivot Table tricks

Power Query, Data model, DAX, Filters, Slicers, Conditional formats and beautiful charts. It's all here.

Still on fence about Power BI? In this getting started guide, learn what is Power BI, how to get it and how to create your first report from scratch.

11 Responses to “Who is the most consistent seller? [BYOD]”

  1. Hui... says:

    The Date column in the sample file is Text not Dates

  2. Great Chandoo. Keep it up, Looking forward more from BYOD..

  3. gayani says:

    Thanks

  4. Frank Tonsen says:

    With Excel 2013 the pivot table could be connected to the data model which provides a distinct count.

  5. Mak says:

    This will do for invoice count
    =COUNTIF(F:F,H12)
    Instead of
    =COUNTIFS(sales[SELLER],$H12)

  6. Alejandro says:

    Excellent document. How did you make the last graphic? Witch app. Thanks for answer.

  7. Chris says:

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

    • Vândalo says:

      Hi Chris,

      =countif(sales [date],sales[date]) function is counting the unique dates in the table.

      Vândalo

  8. Nguyen says:

    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?

  9. TS says:

    Hi,

    Not understood this formula: {=SUMPRODUCT(IF(sales[SELLER]=H12,1/COUNTIFS(sales[SELLER],H12,sales[date],sales[date]),0))}

    Please explain.

    Thanks.

Leave a Reply