Please Note: This article is written for users of the following Microsoft Excel versions: 2007, 2010, and 2013. 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.

Noting the Workbook Creation Date

by Allen Wyatt
(last updated August 10, 2018)

10

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.Name).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:

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 (10234) applies to Microsoft Excel 2007, 2010, and 2013. You can find a version of this tip for the older menu interface of Excel here: Noting the Workbook Creation Date.

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

Resizing a Picture

Place a graphic into a worksheet, and it is inevitable that you'll need to change the size of that graphic. Here's the ...

Discover More

Saving a Workbook Using Passwords

If you want to protect your workbook so that others cannot open or change the information it contains, an easy way to ...

Discover More

Word's Native Measurement Unit

Word allows you to specify distances using a number of different measurement units. Figuring out how those measurement ...

Discover More

Comprehensive VBA Guide Visual Basic for Applications (VBA) is the language used for writing macros in all Office programs. This complete guide shows both professionals and novices how to master VBA in order to customize the entire Office suite for their needs. Check out Mastering VBA for Office 2010 today!

More ExcelTips (ribbon)

Strange Message about Others Making Changes in a Workbook

Have you ever tried to save a workbook, only to be notified that someone else has made changes in it? What if you are the ...

Discover More

Remembering Commonly Used Workbooks

Want a quick way to access the workbooks you use most often? You can "pin" the workbooks so they can be opened with a click.

Discover More

Creating Default Formatting for Workbooks and Worksheets

Not satisfied with the way that default workbooks and worksheets look in Excel? You can easily create your own defaults ...

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 two more than 9?

2018-08-13 10:14:12

David Gray

I like all of the suggestions made by Willy Vanhaelen., and I'll probably incorporate some or all into one of my existing add-ins.

In particular, I've known about the effect that copying a file has on its creation date. However, since this is true of all Windows files, I've known about it, and it's never especially bothered me. However, on the rare occasion when I need to know when a workbook first began to take shape, it's handy to know that Excel keeps that information in its own document properties.

That being the case, I'll keep my existing method of evaluating the creation date of a file, since I use it regularly with all kinds of files, including other types of Office documents, plain text files, and even program files.

As an aside, I have dozens of custom functions defined in a set of Excel add-ins that I started over a decade ago. The beauty of having them defined in add-ins is that I can use them in regular XLSX files. The down side, of course, is that I can't easily distribute those Excel documents or the add-ins to others, since I have yet to find a truly foolproof way to install add-ins on other machines _and_ re-establish links to them on others' machines.


2018-08-12 06:31:28

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.


2018-08-10 12:36:01

Willy Vanhaelen

I don't see the use of the Auto_Open macro. It does it's job when you open the file for the first time but this doesn't necessarly correspond with the date you created it. That could be days ago.

The second macro can be usefull if you remove the bug in it. Indeed as it is presented in this tip it allways returns "Not Saved" because the argument of GetFile is ActiveWorkbook.Name. This returns the name of the workbook without the path which generates an error.

Replace it by ActiveWorkbook.FullName and then the UDF will work.


2018-08-10 11:53:45

David Gray

Years ago, I devised an almost identical function that can return any of the three dates associated with any file, and have used it from time to time to get the created or modified date of a workbook. My generic function is invaluable for keeping track of which of a set of files remains to be updated.


2015-10-13 12:20:45

3R

Can someone provide the definitions for the following?
Created
Modified
Accessed
While the definitions seem evident, I need to prove when a document was saved to the server. Does the Created definition provide the evidence?


2014-12-09 12:03:54

Glenn Case

Also, to answer Paul's question:

ActiveWorkbook.BuiltinDocumentProperties("Last Save Time")


2014-12-09 12:01:27

Glenn Case

This is easier, as you don't need to use scripting. TO access the creation date from VBA, use the following:

ActiveWorkbook.BuiltinDocumentProperties("Creation Date")


2014-12-07 13:35:57

David Harte

(For Paul) I haven't confirmed this but I'm pretty sure that to retrieve when the workbook file was last SAVED the same basic macro can be used but with the Temp variable set to the 'dateLastModified' property instead of the 'dateCreated' property (oh, and the name of the macro no doubt changed to call it SaveDate or something similar).


2014-12-06 07:39:25

sheldon hopkins

An easier (and more informative) method

Add a worksheet to your workbook. In this version history worksheet:
col a date of editing workbook
col b version (incremental)
col c module affected
col d brief description of change

Now you have a record of your workbook's history


2014-12-06 07:03:42

Paul Van den Bossche

Interesting tip !
But ... Is there a way to put the (time and) date in a cel that tells when the sheet was SAVED the last time ?

thanks in advance !


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.