Using a Formula in a Footer

by Allen Wyatt
(last updated March 19, 2016)

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 Mar 2016 through 15 Mar 2016 ($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 desgined 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, and 2016.

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

Printing Copy Numbers

Copy 1, Copy 2, Copy 3... Do you want to mark your printouts so that they are numbered? Here's how you can do it.

Discover More

Creating a Directory in a Macro

One of the things you can do with macros is to work with disk files. As you do so, you may have a need to create a new ...

Discover More

One Change Affects Everything

Have you ever made one formatting change in your document, only to see that change applied to all the paragraphs in the ...

Discover More

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!

More ExcelTips (ribbon)

Using a Different Footer on Secondary Pages

When printing a worksheet, you may want to have the footer different on the first page of your document than it is on ...

Discover More

Putting Cell Contents in Footers

Referencing information between cells in a worksheet is a piece of cake using some elemental formulas. You cannot, ...

Discover More

Copying Headers and Footers

Need to copy headers and footers from one worksheet to another? How about from one workbook to another? Here are some ...

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}] 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 four less than 4?

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 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.