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

Automatically Advancing by a Month

by Allen Wyatt
(last updated December 19, 2015)

6

Jim has a need to advance the date in a particular cell by one month at midnight on the 14/15 of each month (00:00:00 on the 15th), and he wondered how it could be done.

As with many problems in Excel, the answer depends on the nature of the data involved and exactly what you want to do. If the date in the cell is today's date, and you simply want to have the cell display the current month up through the 14th, and then next month after that, then you can use a formula such as the following:

=CHOOSE(IF(DAY(NOW())>14,MONTH(NOW())+1,MONTH(NOW())),
"January","February","March","April","May","June",
"July","August","September","October","November",
"December","January")

This formula returns the name of a month, not a date. If you prefer to have a date returned, you can use this formula:

=IF(DAY(NOW())>14,DATEVALUE(IF(MONTH(NOW())=12,1,
MONTH(NOW())+1) & "/" & DAY(NOW()) & "/" & IF(MONTH(
NOW())=12,YEAR(NOW())+1,YEAR(NOW()))),NOW())

Both of these formulas account for the "end of year wrap-around" when you advance from December to January. A shorter version of this last formula can be created if you use the DATE function instead of the DATEVALUE function:

=DATE(YEAR(NOW()),(MONTH(NOW())+((DAY(NOW())>14)*1),1)

This formula, unlike the DATEVALUE example, always returns a date that is the first day of any given month.

If you really want to advance the value of a particular date in a cell, then you must use a macro to do the task. Further, you must make sure that the macro only runs once a month, at a particular time on a particular day. For instance, if you wanted the macro to run at 00:00:00 on the 15th of each month, you would need to set up the macro so that it checked the date and time, and then ran at that particular date and time. You would also need to make sure that the workbook containing the macro was open over that date and time.

The following macro will fetch the date from a cell and increase it by a month. The macro assumes that you have a named range, DateCell, which refers to the cell to be updated.

Sub IncreaseMonth()
    Dim dDate As Date
    dDate = Range("DateCell").Value
    Range("DateCell").Value = _
      DateSerial(Year(dDate), _
      Month(dDate) + 1, Day(dDate))
End Sub

To make sure that the macro runs at the appropriate time, you would need another macro. The following macro is designed to be run whenever the workbook is opened:

Private Sub Workbook_Open()
If Day(Now) = 14 Then
    Application.OnTime ("23:59:59"), "IncreaseMonth"
End If
End Sub

Notice that this particular macro sets the OnTime method so that it runs the IncreaseMonth macro at 23:59:59 on the 14th. This date and time was chosen because it is easier to catch than is 00:00:00 on the 15th.

Remember that the IncreaseMonth macro will only run if you open the workbook on the 14th, and then leave the workbook open until the 15th.

ExcelTips is your source for cost-effective Microsoft Excel training. This tip (11751) applies to Microsoft Excel 2007, 2010, 2013, and 2016. You can find a version of this tip for the older menu interface of Excel here: Automatically Advancing by a Month.

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

Cross-referencing to an Automatic Number

Word allows you to add automatic numbering to different elements of your document, such as to headings. If you want to create ...

Discover More

Turning Off Figure Caption Numbering

Ever want to use Word's automatic figure captioning feature, without the numbering? While there isn't a way to make this work ...

Discover More

Cannot Set Heading Rows in a Table

Word allows you to specify which rows in a table should be considered headings. What if setting the headings doesn't work ...

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)

Calculating a Date Five Days before the First Business Day

Excel allows you to perform all sorts of calculations using dates. A good example of this is using a formula to figure out a ...

Discover More

Every Second Tuesday

Need a way to enter dates from every second Tuesday (or some other regular interval)? Excel makes it easy, providing several ...

Discover More

The Last Business Day

Many businesses need to know when the last business day of the month occurs. This tip discusses several ways you can ...

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 3 + 8?

2016-10-29 09:54:30

Maurice Ball

1. It is not clear what "Date" Jim wants to advance by a month on the 14/15th of the month. If the Day(dDate)>28 then for some months you will get an invalid result. If you adjust the formula to get a proper date ie, not beyond the end of the next month, like 31 November, you will eventually bring any dates after 28 back to 28.

2. To ensure the you get Valid dates by adding a month I suggest:-

Sub IncreaseMonth()

Dim dDate As Date
dDate = Range("DateCell").Value
Range("DateCell").Value = _
DateAdd("m", 1, dDate)
End Sub


2015-12-22 08:34:14

Michael (Micky) Avidan

@Jeremy,
The general principle is shown hereunder:
--------------------------
Sub Previous Month Name()
' PM1 returns the previous month's name for ANY given date:
PM1 =Application.Text(Application.EoMonth(Now, -1), "MMMM")
' PM2 returns the previous month's name for the FIRST day of a Month:
PM2 = Application.Text(Now - 1, "MMMM")
End Sub
--------------------------
Michael (Micky) Avidan
“Microsoft® Answers" - Wiki author & Forums Moderator
“Microsoft®” MVP – Excel (2009-2016)
ISRAEL


2015-12-21 05:24:57

Barry

@Jeremy

Please post your code here so that suggestions can be made.


2015-12-20 15:10:24

Jeremy

Hi, very useful.
However I'm trying to do something similar, which is saving a file on the first business day of each month, in a folder corresponding to the month of the last business day of the previous month.
The macro works well for any day apart from the first day of the next month.
For instance, if I ran my macro on December 1st, I would like the file to be saved in the November folder, however it saves the file in the December folder.
Do you have any tip to tweak my code please.


2015-12-19 05:38:24

Michael (Micky) Avidan

Unless I misunderstood something - how wrong will I be by using:
=EDATE(NOW(),N(DAY(NOW())>14))
--------------------------
Michael (Micky) Avidan
“Microsoft® Answers" - Wiki author & Forums Moderator
“Microsoft®” MVP – Excel (2009-2016)
ISRAEL


2015-12-19 05:27:58

Jon

=DATE(YEAR(NOW()),(MONTH(NOW())+((DAY(NOW())>14)*1),1)

has an extra ( before MONTH which causes an error.

Should be
=DATE(YEAR(NOW()),MONTH(NOW())+((DAY(NOW())>14)*1),1)


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.