Written by Allen Wyatt (last updated December 11, 2021)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365
When you write a macro, it is designed to be run whenever you choose to run it. What if you need to develop a macro that will run whenever something changes in your worksheet? This is particularly necessary if you are creating a custom function that you want to use within the cells of the worksheet.
This is where it is important to understand what is meant by function volatility. Excel considers a function to be volatile if its value cannot be assumed to be the same from one moment to the next. The following worksheet functions are considered to be volatile in nature:
Even though the list looks short, there is some controversy over what worksheet functions are actually volatile and which ones aren't. The following short article is helpful in understanding this:
https://www.decisionmodels.com/calcsecretsi.htm
What do worksheet functions have to do with macros? Well, you can create a macro that is a UDF (user-defined function) that may fit into the category of not having a value that "can be assumed to be the same from one moment to the next." By default, Excel assumes that any macro you create is non-volatile. This may not be the case, however. Consider the following single-line UDF:
Function FutureDay(D As Integer) As Double FutureDay = Now() + D End Function
All this does is determine the time, right now, and add an integer value to that time in order to deternine a future (or past) date and time. You might call this UDF in a worksheet in this manner:
=FutureDay(7)
That returns a date/time value 7 days in the future. When your worksheet recalculates, though, the UDF doesn't recalculate. This means that the date/time value in the cell is no longer accurate.
The solution is to tell Excel that your UDF is volatile. You do this by adding a single line to the macro:
Function FutureDay(D As Integer) As Double Application.Volatile FutureDay = Now() + D End Function
Now when Excel recalculates the worksheet, it will force a recalculation of your UDF, as well.
You should note that you should only use the Volatile method sparingly in your macros. It doesn't hurt anything to use it everywhere, except it adds additional work to the recalculation of your worksheets. To make sure things run as quickly as possible, just use Volatile where you determine that it is really needed.
Note:
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (10598) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365.
Program Successfully in Excel! John Walkenbach's name is synonymous with excellence in deciphering complex technical topics. With this comprehensive guide, "Mr. Spreadsheet" shows how to maximize your Excel experience using professional spreadsheet application development tips from his own personal bookshelf. Check out Excel 2013 Power Programming with VBA today!
You can easily use formulas to pull apart text stored in a cell. For instance, if you need to pull individual characters ...
Discover MoreExcel allows you to create a special type of macro called a user-defined function (UDF). These can let you add to the ...
Discover MoreIf you create a user form in VBA that includes checkboxes, you may want to make the checkboxes larger. You can't adjust ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
2021-12-13 04:18:50
Alan
I presume a UDF will recalculate should any of it's parameters change? E.g. if your "=FutureDay(had a cell reference here)"?
2021-12-11 11:14:34
J. Woolley
@Allen
I have an issue with the word Macro in the title of this Tip. It should be UDF or User-Defined Function.
The definition of Macro should be consistent with the list of procedures in the Macro dialog that results when you press Alt+F8. In particular, these are Public Sub procedures without parameters; for example,
Public Sub MyMacro()
A UDF is a Public Function procedure that might have parameters; for example, the Tip's FutureDay procedure is a UDF. Application.Volatile is effective only in a UDF that is referenced in a cell formula.
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