Using a Custom Date Format in a Header or Footer

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


2

When Noor creates a custom header or footer, clicking the Date icon adds the code &[Date] to whatever portion of the header or footer he specifies. This adds a rather generic looking date to the header or footer, but he would like a date formatted like "Nov. 23/2021." Noor wonders if there is a way to customize how the date appears in the header or footer.

Normally, when you insert date or time into the header or footer with the &[Date] or &[Time] code, the date or time format is based on the regional settings controlled by Windows. Unfortunately, Excel doesn't provide a way to modify this, and most people won't (for obvious reasons) want to change the regional settings in Windows. So, the solution is to use a macro to add the date in the desired format. Here's a simple example:

Sub ChangeHeaderDate()
    ActiveSheet.PageSetup.RightHeader = Format(Date, "mmm. dd/yyyy")
End Sub

If you want the date to be in a different location in the header or footer, just change the .RightHeader property to .LeftHeader, .CenterHeader, .LeftFooter, .CenterFooter, or .RightFooter, as desired.

You would need to remember to run the macro every time you wanted to change the date in the header. If you prefer to have the date changed automatically whenever you choose to print, you can use an event handler, such as the following:

Private Sub Workbook_BeforePrint(Cancel As Boolean)
    ActiveSheet.PageSetup.CenterHeader = Format(Date, "mmm. dd/yyyy")
End Sub

This usage causes the center portion of the header to be updated for the active worksheet whenever you choose to print. If you often print an entire workbook that had multiple worksheets, then you'll want to change the event handler to something just a bit more complex:

Private Sub Workbook_BeforePrint(Cancel As Boolean)
    Dim w As Worksheet

    For Each w In ThisWorkbook.Worksheets
        w.PageSetup.CenterHeader = Format(Now, "mmm. dd/yyyy")
    Next w
End Sub

It is possible when you run any of these macros that the / in the date format will change to a dash, such that Nov. 23/2021 is changed to Nov. 23-2021. If this happens on your system, it is because Excel is your default date separator, which is a dash. In that case, just modify the format used in your macro to this: "mmm. dd\/yyyy". Adding the backslash causes Excel to interpret the following character (the forward slash) as a literal character.

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 (12017) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365.

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

Clearing Lists in the Insert Hyperlink Dialog Box

Word maintains a series of URLs and file references in the Insert Hyperlink dialog box. How to clear these lists is a ...

Discover More

Extra Blank Lines in Some Cells

When adjusting column width, Excel can add an extra line to some cells. This behavior seems to be related to the text ...

Discover More

Shortening Worksheet Tabs

When worksheet names are quite long, it can present problems in displaying those names in the tabs at the bottom of the ...

Discover More

Professional Development Guidance! Four world-class developers offer start-to-finish guidance for building powerful, robust, and secure applications with Excel. The authors show how to consistently make the right design decisions and make the most of Excel's powerful features. Check out Professional Excel Development today!

More ExcelTips (ribbon)

Changing Page Number Format

Need your page numbers to not appear as regular Arabic numerals? Here's a way to get them to appear in a different ...

Discover More

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

Specifying Date Formats in Headers

Don't like the default date format used by Excel when you place the date in a header or footer? You can use a macro to ...

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

2022-09-05 15:02:37

J. Woolley

For more on this subject, see my comment here: https://excelribbon.tips.net/T007990_Specifying_Date_Formats_in_Headers.html


2021-11-27 11:01:55

Tomek

You can also add a different specific date to your footer. It can be last saved date, file creation date, or a date from a cell in your spreadsheet.
Simply use one of the following in place of Date in your Format formula:

ActiveWorkbook.BuiltinDocumentProperties("Last Save Time")
ActiveWorkbook.BuiltinDocumentProperties("Creation Date")
Range(“A1”).value, "mmm. dd\/yyyy"


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.