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: Displaying the "Last Modified" Date.
Written by Allen Wyatt (last updated November 4, 2023)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, Excel in Microsoft 365, and 2021
If you look at the properties stored with a workbook, you will notice that Excel maintains quite a bit of information concerning the file. One of the items is a date and time that is simply noted as "Modified." Many people refer to this as the "last modified" date, but it really reflects the last time the workbook was saved.
If you want to use this date in your workbook (perhaps in a header or footer), you can do so by using the BuiltinDocumentProperties property (that almost sounds redundant). The following macro will add the proper date to the header of your document:
Sub MyHeader1() Dim sLMD As String On Error Resume Next sLMD = ActiveWorkbook.BuiltinDocumentProperties("Last Save Time") If Err = 440 Then sLMD = "Not Set" End If sLMD = Format(sLMD, "d/m/yyyy") ActiveSheet.PageSetup.LeftHeader = "Last Saved: " & sLMD End Sub
There are a number of items to note in this macro. First of all, it attempts to determine the last date the workbook was saved. If that information cannot be determined, then it sets the header to "Not Set."
Notice that there is some error handling done in this macro. The reason is that Excel will return an error if a particular document property (BuiltinDocumentProperties in this case) is not set. The error needs to be intercepted and handled, which is done here.
There is another item to note here. In some versions of Excel, the Err value returned if the property is not set is not really 440 (as shown here), but some other odd number, such as -2147467259. This is very bizarre, indeed. Why the 440 value (which is the proper error code) would be returned in one circumstance and not in another, I don't know. (Perhaps some other Excel guru will know the answer.) If you have this problem, there are two approaches you can take. First, you can replace the 440 value with the other value (-2147467259). The second option, assuming you have already saved the workbook at least once, is to use a different macro. The following reads the "last modified" attribute from the file itself and stores that info in the header:
Sub MyHeader2() Dim fs As Variant Dim f As Variant Dim sLMD As String Set fs = CreateObject("Scripting.FileSystemObject") Set f = fs.GetFile(ActiveWorkbook.Path & "\" & ActiveWorkbook.Name) sLMD = Format(f.DateLastModified, "d/m/yyyy") ActiveSheet.PageSetup.LeftHeader = "Last Modified: " & sLMD End Sub
Regardless of which macro you use, remember that the macro, once run, will set the left header to the desired information. That information will not change again until you run the macro again. Thus, if you always want an up-to-date date in the header, then you should either run the macro periodically (perhaps right before printing) or set it up to run whenever you open your document.
Note:
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (7764) 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: Displaying the "Last Modified" Date.
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!
Macros are great at working with text. This tip presents an example that shows this versatility by reversing the contents ...
Discover MoreMacros are often used to process the data in a worksheet. If that data includes dates that need to be processed, you'll ...
Discover MoreIf you need to find out how many columns are set to be a specific width, you'll need a macro to help determine the info. ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
2023-11-04 11:55:27
J. Woolley
Here are four ways to get the active workbook's last modified (saved) date using functions available in My Excel Toolbox:
=FileLastDate()
=GetDocProperty("Last Save Time")
=INDEX(ListDocProperties(,,TRUE),12,2)
=VBAResult("ActiveWorkbook.BuiltinDocumentProperties(12)")
Notice "Last Save Time" is the 12th item in BuiltinDocumentProperties.
The first and last formulas return numeric date serial values; the others return text values.
See https://sites.google.com/view/MyExcelToolbox
For related discussion, see the following Tips:
https://excelribbon.tips.net/T011099_Last_Saved_Date_in_a_Footer.html
https://excelribbon.tips.net/T007990_Specifying_Date_Formats_in_Headers.html
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