Quickly Identifying Applied AutoFilters

Written by Allen Wyatt (last updated December 17, 2022)
This tip applies to Excel 97, 2000, 2002, and 2003


Jim wants a way to quickly tell what filtering criteria have been applied in an AutoFilter. He has a hard time telling even which columns have filtering applied (the slight change in drop-down arrow color from black to blue is hardly noticeable), so some other method of telling where a filter is applied would be nice.

The lack of contrast between the black and blue drop-down arrows in a filtered column is not an uncommon complaint. In fact, this very issue was addressed in a different issue of ExcelTips. (You can search at the ExcelTips Web site for the phrase "drop-down arrow colors" for a handy tip in this regard.)

If you actually want to know what criteria are being applied to a column, then you'll be interested in a small macro that will place the criteria into another cell:

Function DispCriteria(Rng As Range) As String
    Dim Filter As String

    Filter = ""
    On Error GoTo Done
    With Rng.Parent.AutoFilter
        If Intersect(Rng, .Range) Is Nothing Then GoTo Done
        With .Filters(Rng.Column - .Range.Column + 1)
            If Not .On Then GoTo Done
            Filter = .Criteria1
            Select Case .Operator
                Case xlAnd
                    Filter = Filter & " AND " & .Criteria2
                Case xlOr
                    Filter = Filter & " OR " & .Criteria2
            End Select
        End With
    End With
Done:
    DispCriteria = Filter
End Function

This is actually a user-defined function that you can use in your worksheet. For instance, if you wanted to know the filtering criteria that was applied to column C, you could use the following in a cell:

=DispCriteria(C:C)

If you prefer, you could simply reference the header cell for the column being filtered. For example, if the header (the one to which AutoFilter adds the drop-down arrow) is cell C3, you could use the following:

=DispCriteria(C3)

The criteria displayed by the function are those actually used by AutoFilter. For instance, if you use a filtering criteria that says "Top 10," then Excel translates that at the time it is applied into something like ">=214.3281932" (the value will vary, depending on your data). It is the formulatic filter that is returned by the DispCriteria function, not the "Top 10" wording.

The function is based on one created by Microsoft MVP Stephen Bullen. The macro has been published in various places, and you can find it on John Walkenbach's Web site, here:

http://www.j-walk.com/ss/excel/usertips/tip044.htm

Note:

If you would like to know how to use the macros described on this page (or on any other page on the ExcelTips sites), I've prepared a special page that includes helpful information. Click here to open that special page in a new browser tab.

ExcelTips is your source for cost-effective Microsoft Excel training. This tip (2891) applies to Microsoft Excel 97, 2000, 2002, and 2003.

Author Bio

Allen Wyatt

With more than 50 non-fiction books and numerous magazine articles to his credit, Allen Wyatt is an internationally recognized author. He is president of Sharon Parq Associates, a computer and publishing services company. ...

MORE FROM ALLEN

Cannot Add Worksheets to a Workbook

If you cannot add a worksheet to your workbook, it could be because the workbook is protected. This tip shows how to ...

Discover More

Default Envelope Margins

When you create envelopes in Word, you may want to adjust where the return address and main address are printed. Doing so ...

Discover More

Special Characters in Fields

If you try to add a quote mark or a backslash as part of a field parameter or switch, you may be surprised at what you ...

Discover More

Professional Development Guidance! Four world-class developers offer start-to-finish guidance for building powerful, robust, and secure applications with Excel. The authors show how to consistently make the right design decisions and make the most of Excel's powerful features. Check out Professional Excel Development today!

More ExcelTips (menu)

Increasing the AutoFilter Drop-Down Limit

When you turn on AutoFiltering, Excel displays a drop-down list at the top of each column in your data table. This list ...

Discover More

Limits to Filtering

Excel limits the number of items that can be shown in an AutoFilter drop-down list. Granted, it is a high limit, but it ...

Discover More

Setting Up Custom AutoFiltering

The filtering capabilities of Excel are very helpful when you are working with large sets of data. You can create a ...

Discover More
Subscribe

FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."

View most recent newsletter.

Comments

If you would like to add an image to your comment (not an avatar, but an image to help in making the point of your comment), include the characters [{fig}] (all 7 characters, in the sequence shown) in your comment text. You’ll be prompted to upload your image when you submit the comment. Maximum image size is 6Mpixels. Images larger than 600px wide or 1000px tall will be reduced. Up to three images may be included in a comment. All images are subject to review. Commenting privileges may be curtailed if inappropriate images are posted.

What is 6 - 0?

There are currently no comments for this tip. (Be the first to leave your comment—just use the simple form above!)


This Site

Got a version of Excel that uses the menu interface (Excel 97, Excel 2000, Excel 2002, or Excel 2003)? This site is for you! If you use a later version of Excel, visit our ExcelTips site focusing on the ribbon interface.

Newest Tips
Subscribe

FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."

(Your e-mail address is not shared with anyone, ever.)

View the most recent newsletter.