Using a Formula in a Footer

Written by Allen Wyatt (last updated August 13, 2022)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, 2021, and Excel in Microsoft 365


2

Skye has three cells on a worksheet that are important. One cell contains a start date, the second contains an ending date, and the third contains a total for the transactions between those dates. He would like to have a footer for the printed page that incorporates these three pieces of data, dynamically. He wonders if there is a way to get a formula into the footer so it can reflect these values.

There is no built-in way to do this in Excel because formulas cannot be entered into footers; they aren't recognized as formulas by the program. You can, however, use a macro to set your footer. Let's assume, for the sake of this approach, that your start date is contained in cell E1, your ending date is in cell E2, and your total of transactions are in cell E3. In that case, you could use a macro like this:

Private Sub Workbook_BeforePrint(Cancel As Boolean)
    Dim sTemp As String

    With Worksheets("Sheet1")
        ' Set wording for date range
        sTemp = .Range("E1").Text & " through " & .Range("E2").Text
        sTemp = sTemp & " (" & .Range("E3").Text & ")"
        .PageSetup.CenterFooter = sTemp
    End With
End Sub

There are a few things to note in this macro. First of all, the macro only sets the footer information in the worksheet named Sheet1, though you can change this worksheet name to whatever you need. Second, notice that the .Text property is used instead of the .Value property. There are actually three ways you could reference the cell contents, as shown here:

sTemp = Worksheets("Sheet1").Range("E1")
sTemp = Worksheets("Sheet1").Range("E1").Value
sTemp = Worksheets("Sheet1").Range("E1").Text

The first two approaches are equivalent; they set sTemp equal to the contents of the cell. The third approach is different; it sets sTemp equal to the formatted text of the cell. In other words, sTemp will be equal to whatever is in cell E1, as it is formatted in the cell. Since you are working with dates and sums, this is the approach you want to use, so it is what was used in the macro.

Third, the macro ends up setting up the footer in the sTemp variable. As written, the macro would create a footer that looked similar to this:

1 Jul 2022 through 15 Jul 2022 ($1,234.56)

Again, the actual appearance depends on the formatting in cells E1, E2, and E3. The macro adds the word "through" and puts parentheses around the sum of transactions. You can modify these additional elements directly within the macro.

Fourth, the macro assigns the formatted sTemp string (your footer) to the center position in the page footer for the worksheet. If you prefer for the footer to be elsewhere, you can simply change the .CenterFooter property to either .LeftFooter or .RightFooter.

Finally, you need to be aware that this macro is designed to be added to the ThisWorkbook module. It is run, automatically, just before the workbook is printed. It is not triggered, however, by looking at the worksheet in Print Preview, so you can't count on what you may see before you actually print.

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 (559) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, 2021, and Excel in Microsoft 365.

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

Upside-Down Printing

Putting words on the printed page is easy in Word. Rotating those words in different manners can be a bit trickier. This ...

Discover More

Combining Cell Contents

Excel allows you to easily combine text together. Interestingly, it provides two ways you can perform such combinations. ...

Discover More

Determining the Number of Bookmarks Defined in a Document

If you develop a macro that needs to work with bookmarks defined in a document, it is inevitable that you will need a way ...

Discover More

Dive Deep into Macros! Make Excel do things you thought were impossible, discover techniques you won't find anywhere else, and create powerful automated reports. Bill Jelen and Tracy Syrstad help you instantly visualize information to make it actionable. You’ll find step-by-step instructions, real-world case studies, and 50 workbooks packed with examples and solutions. Check out Microsoft Excel 2019 VBA and Macros today!

More ExcelTips (ribbon)

Moving Part of a Footer Down a Line

Setting up a single footer line for your printouts is fairly easy. If you want to move part of the footer down a line so ...

Discover More

Using X of Y in a Page Footer

If you want your printed worksheet to include page numbers, adding them is relatively easy. This tip shows two ways that ...

Discover More

Specifying the Y Value in X of Y Page Numbering

Page numbers in Excel headers and footers have always been a source of frustration for users. This tip recounts one ...

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 two minus 1?

2022-09-04 16:06:59

J. Woolley

My Excel Toolbox includes the following function to put Text in a worksheet's headers or footers, which makes them dynamic instead of static:
=SetHeaderFooter(H_F,L_C_R,Text,[FirstPage],[EvenPages],[Target])
The first character of H_F must be H for header or F for footer (alphabetic case ignored).
The first character of L_C_R must be L for left or C for center or R for right (case ignored).
Text must NOT directly reference a volatile function, but indirect reference is OK. Ampersand (&) followed by P, N, D, T, Z, F, or A (case ignored) represents Page, Pages, Date, Time, Path, File, or Tab; otherwise, ampersand (&) will be doubled (&&). The first 255 characters of Text apply.
FirstPage default is FALSE; if TRUE and NOT EvenPages and 'Different first page' (manual), first page header/footer applies.
EvenPages default is FALSE; if TRUE and NOT FirstPage and 'Different odd and even pages' (manual), even pages header/footer applies.
Target identifies the target worksheet. It can be a cell or range on any worksheet in an open workbook; if omitted, the formula's worksheet is assumed.
The function returns text indicating the result or #VALUE!... indicating invalid argument(s). Avoid multiple formulas referring to the same header/footer.
Here is a cell formula for the Tip's example:
=SetHeaderFooter("foot","center",E1&" through "&E2&" ("&E3&")")
See https://sites.google.com/view/MyExcelToolbox


2022-08-13 11:28:13

Brian Lair

Very helpful tip! I especially found the .Value vs. .Text info enlightening. Cheers!


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.