Please Note: This article is written for users of the following Microsoft Excel versions: 97, 2000, 2002, and 2003. If you are using a later version (Excel 2007 or later), this tip may not work for you. For a version of this tip written specifically for later versions of Excel, click here: Showing Filter Criteria on a Printout.
Written by Allen Wyatt (last updated June 25, 2018)
This tip applies to Excel 97, 2000, 2002, and 2003
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 places 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.
Note:
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (3248) applies to Microsoft Excel 97, 2000, 2002, and 2003. You can find a version of this tip for the ribbon interface of Excel (Excel 2007 and later) here: Showing Filter Criteria on a Printout.
Save Time and Supercharge Excel! Automate virtually any routine task and save yourself hours, days, maybe even weeks. Then, learn how to make Excel do things you thought were simply impossible! Mastering advanced Excel macros has never been easier. Check out Excel 2010 VBA and Macros today!
On-screen Excel displays row numbers that help you easily see what is in each row. If you want to print these row ...
Discover MoreExcel allows you to specify certain rows or columns that will be repeated on the pages of a printout. Here's how to set ...
Discover MoreNeed to print a portion of a worksheet, but don't want to waste paper by printing the whole thing? It's easy to print ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
There are currently no comments for this tip. (Be the first to leave your comment—just use the simple form above!)
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.
FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
Copyright © 2024 Sharon Parq Associates, Inc.
Comments