CAUSE
This behavior occurs when the following conditions are true:
- The custom function uses the ActiveCell property.
-and-
- The custom function uses the Volatile method to force the function to recalculate values each time that the worksheet is recalculated.
To see an example of this behavior, see the "More Information" section
later in this article.
WORKAROUND
Microsoft provides programming examples for illustration only, without warranty either
expressed or implied, including, but not limited to, the implied warranties of
merchantability and/or fitness for a particular purpose. This article assumes
that you are familiar with the programming language being demonstrated and the
tools used to create and debug procedures. Microsoft support professionals can
help explain the functionality of a particular procedure, but they will not
modify these examples to provide added functionality or construct procedures to
meet your specific needs. If you have limited programming experience, you may
want to contact a Microsoft Certified Partner or the Microsoft fee-based
consulting line at (800) 936-5200. For more information about Microsoft Certified
Partners, please visit the following Microsoft Web site:
For more information about the support options that are available and about how to contact Microsoft, visit the following Microsoft Web site:
To work around this behavior, substitute
Application.Caller for the
ActiveCell property wherever it is used in the custom function. For example, if the custom function is the following
Function Test()
Application.Volatile
' Returns the cell one column to the left of the active cell. Note
' that the active cell is not necessarily the cell that is calling
' the function.
Test = ActiveCell.Offset(0, -1).Value
End Function
you should change it to the following:
Function Test()
Application.Volatile
' Returns the cell one column to the left of the cell that is
' actually calling the function.
Test = Application.Caller.Offset(0, -1).Value
End Function
When you do this, the function correctly uses the cell that is calling the
function instead of using the currently active cell.
REFERENCES
For additional information about getting help with Visual Basic forApplications, click the article number below
to view the article in the Microsoft Knowledge Base:
226118 OFF2000: Programming Resources for Visual Basic for Applications