Please Note: This article is written for users of the following Microsoft Excel versions: 2007, 2010, 2013, 2016, 2019, Excel in Microsoft 365, and 2021. 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.
Written by Allen Wyatt (last updated April 2, 2022)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, Excel in Microsoft 365, and 2021
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.
Note:
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (11751) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, Excel in Microsoft 365, and 2021. You can find a version of this tip for the older menu interface of Excel here: Automatically Advancing by a Month.
Excel Smarts for Beginners! Featuring the friendly and trusted For Dummies style, this popular guide shows beginners how to get up and running with Excel while also helping more experienced users get comfortable with the newest features. Check out Excel 2013 For Dummies today!
If you store dates in your worksheets, you may want to update those dates at the end of the year. This tip explains ...
Discover MoreIf you need to know the years in which a particular date occurred on a specific day of the week, there are a number of ...
Discover MoreWhen you load data into Excel that was created in other programs, the formatting used for some types of data (such as ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
2022-04-02 13:35:06
Chris Lefsrud
Or a shorter version of the first formula:
=TEXT(EDATE(TODAY(),IF(DAY(TODAY())>14,1,0)),"MMMM")
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