Please Note: This article is written for users of the following Microsoft Excel versions: 2007, 2010, 2013, 2016, 2019, Excel in Microsoft 365, and 2021. 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: Date Last Edited.
Written by Allen Wyatt (last updated July 16, 2022)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, Excel in Microsoft 365, and 2021
As part of setting up a worksheet, you may want the header or footer to contain the date that the workbook was last edited. Excel doesn't maintain this information, but it does allow you to perform macros whenever certain events occur, such as changes to a workbook. All you need to do is add a macro such as the following to the ThisWorkbook object in the VBA Editor:
Private Sub Workbook_SheetChange(ByVal _ Sh As Object, ByVal Target As Excel.Range) ActiveSheet.PageSetup.CenterFooter = _ "Worksheet Last Changed: " & _ Format(Now, "mmmm d, yyyy hh:mm") End Sub
The macro results in each footer on each worksheet in the workbook having separate dates and times on them, since each worksheet would be updated at different times. You can change the destination property (.CenterFooter) to one of the other header or footer properties (.LeftHeader, .CenterHeader, .RightHeader, .LeftFooter, .RightFooter) as desired.
You may want the header or footer to instead include the date that the workbook was last saved. (This is what many people really view as the Òlast edit date.Ó) The information is visible in the Properties dialog box for a worksheet, but Excel has no menu selection or other command that allows you to insert this date into a header or footer. Instead, you must use a macro to add the desired information.
The best way to accomplish the task is to add a macro to the ThisWorkbook object that is triggered just before a workbook is saved:
Private Sub Workbook_BeforeSave(ByVal _ SaveAsUI As Boolean, Cancel As Boolean) Dim sht For Each sht In Sheets sht.PageSetup.CenterFooter = _ "Workbook Last Saved: " & _ Format(Now, "mmmm d, yyyy hh:mm") Next End Sub
This macro steps through each worksheet in the workbook and changes every center footer to have the date that the workbook was saved.
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (11604) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, Excel in Microsoft 365, and 2021. You can find a version of this tip for the older menu interface of Excel here: Date Last Edited.
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!
If you want to copy headers or footers from one worksheet to another, it is a relatively easy process, as described in ...
Discover MoreReferencing information between cells in a worksheet is a piece of cake using some elemental formulas. You cannot, ...
Discover MoreIf you want your printed worksheet to include page numbers, adding them is relatively easy. This tip shows two ways that ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
2022-09-05 15:22:48
J. Woolley
For more on this subject, see my recent comment here: https://excelribbon.tips.net/T011099_Last_Saved_Date_in_a_Footer.html
2022-07-18 10:14:45
J. Woolley
Re. the VBA code in my previous comment:
This line of code
    If Right(sFoot, Len(Divi)) <> Divi Then
should be replaced by this line
    If Len(sFoot) > 0 And Right(sFoot, Len(Divi)) <> Divi Then
However, the code works OK even without this change.
2022-07-17 19:32:04
J. Woolley
Here is the last saved (a.k.a. modified) date and time for the active workbook:
    ActiveWorkbook.BuiltinDocumentProperties("Last Save Time")
The result is a VBA Date type numeric value. The following event code is an alternative to the Tip's Workbook_BeforeSave that might be slightly more efficient. It adds to the end of any unrelated CenterFooter.
Private Sub Workbook_BeforePrint(Cancel As Boolean)
    Dim oSh As Object, dSave As Date, sFoot As String
    Dim n As Integer
    Const Prop As String = "Last Save Time"
    Const Stmt As String = "Workbook Last Saved: "
    Const Divi As String = vbCr
    Const Form As String = "mmmm d, yyyy, hh:mm am/pm"
    dSave = ActiveWorkbook.BuiltinDocumentProperties(Prop)
    For Each oSh In Sheets
        With oSh
            sFoot = .PageSetup.CenterFooter
            n = InStr(1, sFoot, Stmt)
            If n > 0 Then sFoot = Left(sFoot, (n - 1))
            If Right(sFoot, Len(Divi)) <> Divi Then
                sFoot = sFoot & Divi
            End If
            sFoot = sFoot & Stmt & Format(dSave, Form)
            .PageSetup.CenterFooter = sFoot
        End With
    Next oSh
End Sub
2022-07-16 05:34:51
Kiwerry
Thanks, Allen.
Your second macro will add a centre footer to each sheet; it may be worth some user's while to check the centre footer first, e.g by
If Sht.PageSetup.CenterFooter <> "" Then ...
and only update the date if the centre footer exists and has a previous date.
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 © 2024 Sharon Parq Associates, Inc.
Comments