Please Note: This article is written for users of the following Microsoft Excel versions: 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365. 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: Last Saved Date in a Footer.

Last Saved Date in a Footer

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


7

Lori wants the right side of the footer for her worksheet to include the date the workbook was last saved. Every time she tries to create a formula to do this, Excel displays an error message that states the "string is too long" and that she needs to delete some characters. She's not sure she understands why this is happening or how she can get the date she wants in the footer.

There is no actual formula that can put the last-saved date in a footer. Excel has no way (unlike Word) to put this tidbit of information there. There is a way you can do it, but the solution requires the use of a macro. The reason is because you are accessing system information—information outside of Excel itself—and that information can only be retrieved using a programming language such as VBA.

One approach is to add some code that runs whenever a workbook is saved. The code would update the desired footer with the current date:

Private Sub Workbook_BeforeSave(ByVal SaveAsUI As Boolean, _
  Cancel As Boolean)

    ActiveWorksheet.PageSetup.RightFooter = _
      "Last Saved: " & Format(Date, "mmmm d, yyyy")
End Sub

This macro, which should be stored in the ThisWorkbook object for the workbook you want to affect, updates the footer for the currently active worksheet. If you want to affect all the worksheets in a workbook, then a small change to the macro is in order:

Private Sub Workbook_BeforeSave(ByVal SaveAsUI As Boolean, _
  Cancel As Boolean)
    Dim sht As Worksheet

    For Each sht In Sheets
        sht.PageSetup.RightFooter = _
          "Last Saved: " & Format(Date, "mmmm d, yyyy")
    Next
End Sub

If today is December 11, 2021, then after running the macro (which is done automatically when saving), the right footers will all be set to "Last Saved: December 11, 2021".

You can also rely upon the file save date stored in Excel's built-in properties. The way you put that date into the footer is as follows:

Sub RightFooterLastSaved()
     ActiveSheet.PageSetup.RightFooter = _
       ActiveWorkbook.BuiltinDocumentProperties(12)
End Sub

The drawback to this macro is that you need to remember to run it periodically, so it is not quite as automatic as the previous approaches. You could, however, place the single line at the heart of the macro into the Workbook_BeforePrint event handler.

There is another approach you can use. This one involves requesting from Windows the actual date and time a file was saved.

Private Sub Workbook_Open()
    Dim sTemp As String
    Dim sht As Worksheet

    sTemp = FileDateTime(ActiveWorkbook.FullName)
    sTemp = "Last Saved: " & sTemp
    For Each sht In Sheets
        sht.PageSetup.RightFooter = sTemp
    Next sht
End Sub

This macro is designed to run whenever a workbook is first opened—it is saved as the Workbook_Open procedure of the ThisWorkbook object. The workhorse of the macro is the line that calls the FileDateTime function. This function can be used to determine the date and time any file was saved. It requires a full path name of a file, which is supplied by the FullName property of the ActiveWorkbook object. This date and time is then placed in the right footer of all the worksheets in the workbook.

Remember, as well, that the limit of what you can place into each section of the header or footer is approximately 250 characters. So if you adjust the macros to add more information to the right portion of the footer, make sure that it doesn't add up to that many characters, or you may have problems with the macro.

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 (11099) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365. You can find a version of this tip for the older menu interface of Excel here: Last Saved Date in a Footer.

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

Locating Locked Fields

A field can be locked or unlocked, and its condition controls whether it is updated automatically or not. If you want to ...

Discover More

Counting Changed Words

Track Changes is a handy tool for those who need to see how a document changes over time. If you have a long document ...

Discover More

Separating Cells Based on Text Color

If the font color used for the data in your worksheet is critical, you may at some time want to move cells that use a ...

Discover More

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 2013 Data Analysis and Business Modeling today!

More ExcelTips (ribbon)

Changing Section Headers

Add subtotals to a worksheet and you can instruct Excel to start each new subtotal section on a new printed page. You may ...

Discover More

Putting a Different Date in a Header

Today's date is easy to add to a header, but what if you want to add a date that is adjusted in some manner? Adding ...

Discover More

Sequential Page Numbers Across Worksheets

How do you want your page numbers to appear on your printed worksheets? Chances are good that you want them to be ...

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

2023-10-03 15:49:28

J. Woolley

My latest comment below describes three ways to get the last saved date using My Excel Toolbox. Here is another way to return the value of that built-in document property:
=GetDocProperty("last save",TRUE)
For details, see my recent comment here: https://excelribbon.tips.net/T012333


2022-09-05 14:35:41

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])
See https://excelribbon.tips.net/T000559_Using_a_Formula_in_a_Footer.html for a complete description. There are several ways to get the last saved date using My Excel Toolbox:
=FileLastDate()
=INDEX(ListDocProperties(,,TRUE),12,2)
=VBAResult("ActiveWorkbook.BuiltinDocumentProperties(12)")
Assuming cell $A$1 contains one of these (with Date format), Lori could use the following formula to set the right footer with the workbook's last saved date:
=SetHeaderFooter("footer","right",$A$1)
See https://sites.google.com/view/MyExcelToolbox


2022-04-19 10:02:11

J. Woolley

@Chris Gough
Good catch!


2022-04-18 05:36:42

Chris Gough

Hi There,

A bit late, but on the first macro I'd to change ActiveWorksheet.PageSetup.RightFooter to ActiveSheet.PageSetup.RightFooter to get this to work.

Thanks,

Chris


2021-12-12 10:12:37

J. Woolley

@Craig Buback
There is no Document_BeforeSave event for Word; however, you can use the Application.DocumentBeforeSave event. See https://docs.microsoft.com/en-us/office/vba/api/word.application.documentbeforesave


2021-12-11 09:42:52

Craig Buback

Love this Workbook _BeforeSave sub. Will this or a similar macro work for Word?


2021-12-11 05:16:04

Simon Freeman

Allen - couldn't you put one of these macros as a "BeforePrint" event so that when you printed the sheet, the macro would run first, update the last saved date and then print. The problem is that you might have updated the sheet after you last saved it, so perhaps the BeforePrint macro could also ask you if you want to save before printing, save if you say yes, then insert the last saved date and then print.


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.