Please Note: This article is written for users of the following Microsoft Excel versions: 2007, 2010, 2013, 2016, 2019, and 2021. 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: Dynamic Headers and Footers.
Written by Allen Wyatt (last updated December 4, 2021)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, and 2021
If you have a large worksheet, you may want to print it out in "parts" and automatically vary the information contained in the header or footer of each part. There is no intrinsic way to do this in Excel; the best approach is a macro to do the following:
Notice that these steps require the use of named ranges. You could have a named range for each portion of the worksheet that you want to print, and a named range (which would be a single cell) that represents the header or footer information that you want for each print area. The following macro will implement the above steps:
Sub PrintRegions()
Dim x As Integer
'Change the dimension of the arrays to equal the number
' of printing areas you have
Dim Region(4) As String
Dim Head(4) As String
'Fill this array with the names of the ranges to be printed
Region(1) = "North"
Region(2) = "South"
Region(3) = "East"
Region(4) = "West"
'Fill this array with the names of the ranges to be in the header
Head(1) = "NorthHead"
Head(2) = "SouthHead"
Head(3) = "EastHead"
Head(4) = "WestHead"
For x = 1 To UBound(Region)
ActiveSheet.PageSetup.PrintArea = Range(Region(x)).Address
ActiveSheet.PageSetup.LeftHeader = Range(Head(x))
ActiveWindow.SelectedSheets.PrintOut Copies:=1
Next
End Sub
This example prints out only four areas of a worksheet. These areas are named ranges: North, South, East, and West. Similarly, the named ranges—which are really single cells—used for the left portion of the headers are NorthHead, SouthHead, EastHead, and WestHead.
Note:
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (10848) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, and 2021. You can find a version of this tip for the older menu interface of Excel here: Dynamic Headers and Footers.
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!
Need to show a custom date in the header or footer of a printout? You'll need to resort to using a macro, as described in ...
Discover MoreExcel won't let you place a formula directly into a footer. You can, however, create a simple macro that will produce the ...
Discover MoreEver wish that you could create nice, long footers that appear at the bottom of each page when you print your worksheet? ...
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 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.
FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
Copyright © 2025 Sharon Parq Associates, Inc.
Comments