Written by Allen Wyatt (last updated November 27, 2021)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365
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:
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.
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!
When you have a worksheet that includes a long list of names, you may want the first and last names on each page to ...
Discover MoreWhen adding headers or footers to your worksheets, you may want to include the date that the workbook was last edited. ...
Discover MoreDo you want to change the headers and footers that appear on different pages of your printout? Here's how you can get ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
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"
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