Written by Allen Wyatt (last updated May 8, 2021)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365
Kathy needs a formula that will change any date within the current month to the last day of the previous month. She also notes that it would be helpful to have a VBA macro that could do this to the dates in a range of selected cells.
There are actually several different formulaic approaches you could use to derive the desired date. These two are the shortest and easiest to use:
=A1-DAY(A1) =EOMONTH(A1,-1)
The first one works because "day 0" of the current month is always considered to be the last day of the previous month. Thus, if the date in cell A1 is 9/25/21 you end up subtracting 25 (the DAY value) from that day, giving a date of 9/0/21, or 8/31/21.
The second formula works because of the inclusion of the second parameter for the EOMONTH function. This parameter is used to indicate how many months in the past (negative) or future (positive) the end of the month should be calculated.
In either case, you may need to format the cell containing the formula as a date. If you don't, what you see may be the underlying serial number used by Excel to calculate dates.
If you want a macro that will actually convert dates in a selected range into the last day of the previous month, the following will do the trick.
Sub LastDayPreviousMonth() Dim rCell As Range For Each rCell In Selection If IsDate(rCell) And Not rCell.HasFormula Then rCell.Value = WorksheetFunction.EoMonth(rCell.Value, -1) End If Next rCell End Sub
The macro steps through each cell in the selected range and checks to see if it contains a date and is not a formula. (In other words, if the date in a cell is the result of a formula, the formula is not changed.) The EOMONTH function is then used, as previously described, to calculate the desired date.
It should be mentioned that the macro approach will also convert textual dates. For instance, if a cell contains, as text, the date "6/15/21," then the macro will change it to 5/30/21. Once the adjusted date is stuffed back into the cell, it will show as a date/time serial number, not as text.
Note:
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (13304) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365.
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!
Want to add an ordinal suffix to a number, as in 2nd, 3rd, or 4th? Excel doesn't provide a way to do it automatically, ...
Discover MoreIt can be handy to know when specific weekdays occur within a range of dates. Figuring out this information, using ...
Discover MoreNeed to copy a range of dates and update them to a different year? Here are a number of ways to accomplish this task with ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
2021-05-08 11:38:26
Rick Rothstein
You have these two lines of code in your LastDayPreviousMonth macro...
For Each rCell In Selection
If IsDate(rCell) And Not rCell.HasFormula Then
Rather than checking inside the loop to see if each cell does not having a formula in it, eliminate that part of the check and let Excel filter the cells you look at instead. To do that change the above two lines of code to these...
For Each rCell In Selection.SpecialCells(xlConstants)
If IsDate(rCell) Then
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