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: Noting the Workbook Creation Date.
Written by Allen Wyatt (last updated November 5, 2024)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365
When you are developing a worksheet, you may need to keep track of certain information about your workbook. For instance, you might want to place the creation date of a workbook into a cell. While Excel does provide some worksheet functions for dates (such as NOW or TODAY), it does not provide a worksheet function to access the workbook creation date.
This means that the answer lies in using a macro. For instance, you might create a macro that would determine the current date and input it (as text) into a particular cell. This macro could then be run whenever you created a new workbook by naming the macro Auto_Open. The following is an example of such a macro:
Sub Auto_Open() If Worksheets.Application.Range("A1") = "" Then Worksheets.Application.Range("A1") = Format(Date, "long Date") End If End Sub
The macro checks to see what is in cell A1. If there is nothing there, then it puts the text version of today's date in there. If there is something already there (which there would be every time you subsequently open the workbook), then the information is left intact and unscathed.
Perhaps the most satisfactory approach, however, is to actually access the operating system and pull the file creation date for the current workbook. This can be done with the following macro function:
Function CreateDate() As String Dim Temp As String On Error Resume Next Temp = CreateObject("scripting.filesystemobject"). _ GetFile(ActiveWorkbook.FullName).dateCreated If Err.Number <> 0 Then CreateDate = "Not Saved" Else CreateDate = Left(Temp, InStr(Temp, " ") - 1) End If On Error Goto 0 End Function
Notice that this approach isn't tied to a particular cell in your worksheet. To use the macro, simply put the following in any cell of your worksheet:
=CreateDate()
The function returns either "Not Saved" (if the workbook is brand new and hasn't been saved before) or it returns a text value that represents the date on which the workbook was created.
Note:
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (10234) 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: Noting the Workbook Creation Date.
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!
Salvaging information from a corrupted workbook can be a lot of work. This tip looks at how you can approach the problem ...
Discover MoreWhen you open a workbook, Excel displays the worksheet that was visible when the workbook was last saved. You may want, ...
Discover MoreExcel keeps track of a range of stats about each workbook you use. If you want to take a look at those stats, it's easy; ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
2024-11-06 11:09:35
J. Woolley
@Allen
Thank you for providing interesting Excel Tips like this one.
The header of each Tip includes "(last updated...)" date. This is often the date of the most recent comment.
Suggestion: It would be useful if you included a creation date for each Tip. Of course, this would probably be impossible for old Tips, but perhaps it can be considered going forward.
Applicable to this Tip, Willy Vanhaelen's comment below discusses workbook document properties. For more on that subject, see my recent comment here: https://excelribbon.tips.net/T009727
2024-11-05 15:07:48
gary haas
I have found CREATION DATE for files to be suspect. If I copy a file from another drive / source, CREATION DATE becomes the date of the copy. MODIFIED DATE retains the expected date. CREATION DATE is later than MODIFIED DATE in these cases.
2021-09-12 09:09:11
Willy Vanhaelen
Experimenting with the implementation of this tip's idea I became interested in knowing the creation date of some of my workbooks. I found out that the creation date returned by FileSystemObject (Windows) used in this tip's UDF is not reliable. When you copy a file, Windows shows the copy date as creation date. When you continue working with the copy you get a false creation date. So I did some more investigation and discovered that Excel keeps record of the real creation date that can be accesses through vba with BuiltinDocumentProperties("Creation Date").
So I inserted a macro in my personal macro collection:
Sub Created()
MsgBox ActiveWorkbook.BuiltinDocumentProperties("Creation Date"), ,"Creation date of active file"
End Sub
Having created a button in the QAT for this macro I can find out the creation date of any open workbook in the blink of an eye, eliminating the need of any UDF associated with a formula somewhere in a worksheet.
If you prefer to use one of the macros of this tip, you can drastically simplify them by using BuiltinDocumentProperties.
Sub Auto_Open() 'or better: Private Sub Workbook_Open()
Worksheets(1).Range("A1")=ActiveWorkbook.BuiltinDocumentProperties("Creation Date")
End Sub
No need to check if A1 already has a date because it won't change.
Function CreateDate()
CreateDate = ActiveWorkbook.BuiltinDocumentProperties("Creation Date")
End Function
If you enter =CreateDate() in a brand new workbook that hasn't been saved before, the current date is displayed, so there is no need for error catching.
Format the cell containing the creation date to your liking.
2020-07-01 17:22:15
John Mann
This seems a bit elaborate to me. Instead of all that typing to enter the name of a fucntion, why not simply use the keyboard short cut Ctrl+;, which inserts todays date into the active cell. One typing opperation using 2 keys simultaneaously, instead of 12 keystrokes. I'm lazy (gr).
Or am I missing something here.
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