Please Note: This article is written for users of the following Microsoft Excel versions: 2007, 2010, 2013, and 2016. If you are using an earlier version (Excel 2003 or earlier), this tip may not work for you. For a version of this tip written specifically for earlier versions of Excel, click here: Showing Filter Criteria on a Printout.

Showing Filter Criteria on a Printout

by Allen Wyatt
(last updated February 27, 2016)

3

Microsoft Excel includes some great tools that help you filter large data tables to include only the information you want displayed. In effect, the filters allow you to "slice and dice" your data until you get just what you want.

When printing out filtered data, you might want to know what slicing and dicing was done to the original data. There are several ways you can go about displaying your filtering criteria. One simple way is to use the advanced filtering capabilities of Excel, which require that you set up a small criteria table for your data. If the criteria table is made part of what you print, then you can see your filtering criteria quite easily.

If you use AutoFilter, then you need to use a different approach. One such approach is detailed at John Walkenbach's site:

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

This solution uses a user-defined function to return any filtering criteria in use in the current column. The function can be used in a cell in that column to display the criteria. If you are using advanced filtering, then the macro approach is a bit more complex. The following macros (there are two of them in the listing) examine what advanced criteria are in play, and then place the criteria in the left portion of the header.

Sub AddFilterCriteria()
    Dim strCriteria As String

    strCriteria = FilterCriteria()
    If strCriteria = "" Then
        strCriteria = "No Filtering Criteria"
    Else
        strCriteria = "Filter Criteria:" & Chr(10) & strCriteria
    End If

'   add Criteria string to Header/Footer
    With ActiveSheet.PageSetup
        .LeftHeader = strCriteria
    End With
End Sub

Function FilterCriteria() As String
    Dim rngCriteria As Range, col As Range, cel As Range
    Dim strCriteria As String, r As Integer, c As Integer
    Const strCriteriaRange As String = "Criteria"

    FilterCriteria = ""

    On Error Resume Next
    'Set Criteria-Range reference
    Set rngCriteria = Range(strCriteriaRange)
    If Err <> 0 Then Exit Function
    On Error GoTo 0

'   Create Criteria String
    c = 0
    For Each col In rngCriteria.Columns
        c = c + 1     ' CriteriaRange Columns
        r = 1         ' CriteriaRange Rows
        For Each cel In col.Cells
            If r = 1 Then
                strCriteria = strCriteria & "Criteria" _
                  & c & " (" & cel.Value & ") = "
            Else
                strCriteria = strCriteria & "'" & cel.Value & "'"
                If IsEmpty(cel.Offset(1, 0)) Then
                    'Add New row Char if not Last Criteria Column
                    If c < rngCriteria.Columns.Count Then
                        strCriteria = strCriteria & Chr(10)
                    End If
                    Exit For
                End If
                strCriteria = strCriteria & "  "
            End If
            r = r + 1
        Next cel    ' next criteria row
    Next col        ' next criteria column

    FilterCriteria = strCriteria
End Function

To use the macro, just run the AddFilterCriteria macro, after you have your advanced filtering set up. The macro reads the criteria table and puts together the criteria into a string that is placed in the left header.

ExcelTips is your source for cost-effective Microsoft Excel training. This tip (11649) applies to Microsoft Excel 2007, 2010, 2013, and 2016. You can find a version of this tip for the older menu interface of Excel here: Showing Filter Criteria on a Printout.

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

Formatting Datasheet Numbers

Controlling the appearance of numbers in a datasheet.

Discover More

Counting Odds and Evens

If you have a series of values in a range of cells, you may wonder how many of those values are even and how many are odd. ...

Discover More

Viewing a Revision History for a Document

Need to know how a document has evolved over time? Docs has your document's history available at all times. How you access ...

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

Removing Filters and Unhiding Rows and Columns on Multiple Worksheets

Need to remove filters and display all rows and columns in all your worksheets? It is not easy to do manually, but with a ...

Discover More

Using a Filtered Value in a Formula

Accessing filtering criteria for use in a formula can be a real need for some worksheet designs. Getting to that information ...

Discover More

Filtering Columns

The filtering tools provided in Excel make it easy to filter a data list so that only certain rows are displayed. What if you ...

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}] 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 8 - 2?

2017-03-08 11:49:29

Tom Dziubakowski

Note: The J-Walk link doesn't work..... Just thought you would like to know


2016-02-29 10:56:20

Gary Lundblad

What if you want to display the filters used in a pivot table? Will these macros still work?

Thank you!

Gary


2016-02-27 17:34:31

Peter

The link to John Walkenbach's site doesn't work


This Site

Got a version of Excel that uses the ribbon interface (Excel 2007 or later)? This site is for you! If you use an earlier version of Excel, visit our ExcelTips site focusing on the menu 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.