Header and Footer Background Color

Written by Allen Wyatt (last updated April 4, 2020)
This tip applies to Excel 97, 2000, 2002, and 2003


Leonid asked if there was a way to set a background color for the header or footer of a page. The simple answer is that there isn't such a capability in Excel. There are a couple of ways around the issue, however. For instance, if you are using Excel 2002 or Excel 2003 you can add a graphic to a header or footer. With the right graphic, you can make it appear that the header and footer contain color when, in fact, it is the graphic that contains the color.

Another option is to make "fake" headers and footers. If all you want to do is have a different color header, then you can use the first couple of rows of the worksheet as your header. These rows you could format as desired, including setting the color of the rows. You could then instruct Excel to repeat those rows at the top of every page of the printout (us the Page Setup dialog box for this).

Repeating rows for the footer area becomes more problematic, as Excel doesn't include a feature that allows you to repeat rows at the bottom of each page. Creating a macro to add rows for the header and footer is possible, but it does result in a change to your worksheet—rows need to be added for the fake headers and footers.

As an example, consider the following macro. It assumes that you want one-inch borders on the left and right of the printout, and that you want to print only 46 rows per page. It sets the margins and then steps through the worksheet, adding the fake header and footer rows, as necessary. (Because the macro adjusts the design of the worksheet, make sure you save your worksheet before running the macro.)

Sub FakeHeaderFooter()
    Dim LHeader As String
    Dim CHeader As String
    Dim LFooter As String
    Dim CFooter As String
    Dim CBottom As Integer
    Dim CRow As Integer
    Dim PageSize As Integer
	
    LHeader = "Top Left"
    CHeader = "Top Center"
    LFooter = "Bottom Left"
    CFooter = "Bottom Center"
    PageSize = 46

    With ActiveSheet.PageSetup
        .PrintTitleRows = ""
        .PrintTitleColumns = ""
        .PrintArea = ""
        .LeftHeader = ""
        .CenterHeader = ""
        .RightHeader = ""
        .LeftFooter = ""
        .CenterFooter = ""
        .RightFooter = ""
        .LeftMargin = Application.InchesToPoints(1)
        .RightMargin = Application.InchesToPoints(1)
        .TopMargin = Application.InchesToPoints(0)
        .BottomMargin = Application.InchesToPoints(0)
        .HeaderMargin = Application.InchesToPoints(0)
        .FooterMargin = Application.InchesToPoints(0)
        .PrintHeadings = False
        .Orientation = xlPortrait
    End With

    CBottom = Range("A16000").End(xlUp).Row

    CRow = 1
    Do Until CRow > CBottom
        If CRow Mod PageSize = 1 Then
            Rows(CRow).Select
            Selection.Insert Shift:=xlDown
            Selection.Insert Shift:=xlDown
            CBottom = CBottom + 2

            Cells(CRow, 1).Value = LHeader
            Cells(CRow, 4).Value = CHeader
            Range(Cells(CRow, 1), _
              Cells(CRow, 8)).Interior.ColorIndex = 34
            Range(Cells(CRow + 1, 1), _
              Cells(CRow + 1, 8)).Interior.ColorIndex = xlNone
            CRow = CRow + 2
        ElseIf CRow Mod PageSize = PageSize - 1 Then
            Rows(CRow).Select
            Selection.Insert Shift:=xlDown
            Selection.Insert Shift:=xlDown
            CBottom = CBottom + 2

            Cells(CRow + 1, 1).Value = LFooter
            Cells(CRow + 1, 4).Value = CFooter
            Range(Cells(CRow + 1, 1), _
              Cells(CRow + 1, 8)).Interior.ColorIndex = 34
            CRow = CRow + 2
        Else
            CRow = CRow + 1
        End If
    Loop

    LastPageNumber = PageNumber + 1
    LastRow = LastPageNumber * PageSize
    If CBottom <> LastRow Then
            Range(Cells(LastRow, 1), _
              Cells(LastRow, 8)).Interior.ColorIndex = 34
            Cells(LastRow, 1).Value = LFooter
            Cells(LastRow, 4).Value = CFooter
    End If

    CBottom = Range("A16000").End(xlUp).Row

    CRow = 2
    Do Until CRow > CBottom
        If CRow Mod PageSize = 1 Then
            Cells(CRow, 1).PageBreak = xlManual
        End If
        CRow = CRow + 1
    Loop
End Sub

To change the number of lines per page, just change the value assigned to the PageSize variable. You can also change what appears in the "header" and "footer" area by changing what is assigned to the LHeader, CHeader, LFooter, and CFooter variables.

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

Rubbish In Your File

Do your files look garbled when you open them? Here's one possible reason.

Discover More

Rounding To the Nearest Even Integer

Do you need your numbers to be rounded to an even integer value? How you accomplish the task depends on the nature of the ...

Discover More

Finding and Replacing Text in Notes and Comments

Excel allows you to add comments to individual cells in your workbook. Unfortunately, Excel doesn't provide a way to ...

Discover More

Best-Selling VBA Tutorial for Beginners Take your Excel knowledge to the next level. With a little background in VBA programming, you can go well beyond basic spreadsheets and functions. Use macros to reduce errors, save time, and integrate with other Microsoft applications. Fully updated for the latest version of Office 365. Check out Microsoft 365 Excel VBA Programming For Dummies today!

More ExcelTips (menu)

Multiple Line Headers and Footers

When working with headers and footers in a macro, you might find this tip helpful. It describes how you can create ...

Discover More

Putting Headers and Footers On Multiple Worksheets

You can easily create headers and footers for multiple worksheets by working with a selection set of the worksheets you ...

Discover More

Header and Footer Formatting Codes

When creating headers and footers in an Excel worksheet, you can use special codes to add or format information. This tip ...

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 8 - 1?

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.