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

Making Text Bold

Want a cool shortcut to make your text bold? Here's a method that fits in wonderfully with how things are done in the ...

Discover More

Clip Art Sizing Difficulties

A discussion of problems a reader was having resizing clip art in Word.

Discover More

Speeding Up Large Worksheets

If your worksheet gets large enough, you may notice a severe slowdown when it is recalculated. This tip provides some ...

Discover More

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!

More ExcelTips (ribbon)

Adding Last-Row Data to a Page Footer

If you want to modify information that appears in the footer of a worksheet printout, on a page-by-page basis, you can ...

Discover More

Copying Headers and Footers

Need to copy headers and footers from one worksheet to another? How about from one workbook to another? Here are some ...

Discover More

Moving Part of a Footer Down a Line

Setting up a single footer line for your printouts is fairly easy. If you want to move part of the footer down a line so ...

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 one less than 9?

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.