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

Picking a Group of Cells

Excel makes it easy to select a group of contiguous cells. However, it also makes it easy to select non-contiguous groups ...

Discover More

Adding Your Own Menu Items

Want to really make Excel reflect how you work? Why not make some changes to the menu structure so that the menus have ...

Discover More

Deleting the Open Document File

Want to delete the document you are currently viewing? Word doesn't provide a way to do it, but you can use the macro in ...

Discover More

Excel Smarts for Beginners! Featuring the friendly and trusted For Dummies style, this popular guide shows beginners how to get up and running with Excel while also helping more experienced users get comfortable with the newest features. Check out Excel 2013 For Dummies today!

More ExcelTips (menu)

Toggling AutoFilter

Want a tool that will help you toggle AutoFilter on and off? Excel provides some tools you can use, but you need to be ...

Discover More

Using AutoFiltering

Excel's AutoFilter tool is a great way to make a long list of items much more manageable. This tip explains how to set up ...

Discover More

Changing AutoFilter Drop-Down Arrow Colors

The drop-down arrow used at the top of columns by AutoFilter can be difficult to see. Here's a way you can reduce the ...

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 5 + 2?

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.