Written by Allen Wyatt (last updated December 28, 2024)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, 2021, and Excel in Microsoft 365
When working with large worksheets, it is not unusual to add subtotals so that you can group information in the worksheet in some logical manner. (The Subtotal tool is on the Data tab of the ribbon in the Outline group.) When adding subtotals, you can specify that Excel start each group on a brand-new page. This is very handy for all types of reporting in Excel.
If you start each group or subtotal section on a new page, you may wonder if there is a way to create custom headers that print differently for each section, similar to what you can do with different sections in a Word document. Unfortunately, there is no way to do this in Excel. You can, however, create a macro that iteratively changes the heading and prints each group of a worksheet. Consider the following macro:
Sub ChangeSectionHeads()
Dim c As Range, rngSection As Range
Dim cFirst As Range, cLast As Range
Dim rowLast As Long, colLast As Integer
Dim r As Long, iSection As Integer
Dim iCopies As Variant
Dim strCH As String
Set c = Range("A1").SpecialCells(xlCellTypeLastCell)
rowLast = c.Row
colLast = c.Column
iCopies = InputBox( _
"Number of Copies", "Changing Section Headers", 1)
If iCopies = "" Then Exit Sub
Set cFirst = Range("A1") ' initialization start cell
For r = 2 To rowLast ' from first row to last row
If ActiveSheet.Rows(r).PageBreak = xlPageBreakManual Then
Set cLast = Cells(r - 1, colLast)
Set rngSection = Range(cFirst, cLast)
iSection = iSection + 1
Select Case iSection
' substitute your CenterSection Header data ...
Case 1: strCH = "Section 1"
Case 2: strCH = "Section 2"
' etc
' Case n: strCH = "Section n"
End Select
ActiveSheet.PageSetup.CenterHeader = strCH
rngSection.PrintOut _
Copies:=iCopies, Collate:=True
Set cFirst = Cells(r, 1)
End If
Next r
' Last Section ++++++++++++++++++++++++++++
Set rngSection = Range(cFirst, c)
iSection = iSection + 1
' substitute your Center Header data ...
strCH = "Last Section ..."
ActiveSheet.PageSetup.CenterHeader = strCH
rngSection.PrintOut _
Copies:=iCopies, Collate:=True
End Sub
This macro is a good start toward accomplishing what you want to do. It starts by asking you how many copies you want to print of each section, and then it starts to go through each row to see if there is a page break before that row.
The actual row checking is done by looking at the PageBreak property of each row. This property is normally set to xlPageBreakNone, but when you use the Subtotals feature of Excel, any row that has a page break before it has this property set to xlPageBreakManual. This is the same setting that would occur if you manually placed page breaks in your worksheet.
If the macro detects that a row has a page break before it, then the rngSection range is set equal to the rows in the previous group. Also, the Select Case structure is used to set the different headings used for the different sections of the worksheet. This heading is then placed in the center position of the header, and the range specified by rngSection is printed.
After stepping through all the groups in the worksheet, the final group (which does not end with a page break) is printed.
In order to use this macro, all you need to do is specify within the Select Case structure the different headings you want for each section of the worksheet. You can also, if desired, change where the heading is placed in the header. All you need to do is change the CenterHeader property to LeftHeader or RightHeader. You can also use LeftFooter, CenterFooter, and RightFooter, if desired.
Note:
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (9867) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, 2021, and Excel in Microsoft 365.
Solve Real Business Problems Master business modeling and analysis techniques with Excel and transform data into bottom-line results. This hands-on, scenario-focused guide shows you how to use the latest Excel tools to integrate data from multiple tables. Check out Microsoft Excel Data Analysis and Business Modeling today!
When adding headers or footers to your worksheets, you may want to include the date that the workbook was last edited. ...
Discover MoreDo you find that there is a lot of extra space around the data on your worksheet when it is printed? Changing the margins ...
Discover MorePage numbers in Excel headers and footers have always been a source of frustration for users. This tip recounts one ...
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