Function Using ActiveCell Property Returns Incorrect Result (172760)
The information in this article applies to:
- Microsoft Excel 97 for Windows
- Microsoft Excel for Windows 95
- Microsoft Excel for Windows 5.0
- Microsoft Excel 98 Macintosh Edition
This article was previously published under Q172760 SYMPTOMS
When you enter a formula that calls a custom function, the formula may
return an incorrect result when you recalculate the worksheet. The formula
returns the correct result only when you select the cell that contains the
formula and then recalculate the worksheet. When you do this, other
formulas that call the same custom function return the same result.
CAUSE
This problem 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 the worksheet is recalculated.
To see an example of this problem, see the "More Information" section
later in this article.
WORKAROUNDMicrosoft provides programming examples for illustration only, without warranty either expressed or implied. This includes, but is not limited to, the implied warranties of merchantability or fitness for a particular purpose. This article assumes that you are familiar with the programming language that is being demonstrated and with the tools that are used to create and to debug procedures. Microsoft support engineers 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 requirements.
To work around this problem, substitute "Application.Caller" for
"ActiveCell" 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
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.
STATUS
This behavior is by design of the versions of Microsoft Excel listed at the
beginning of this article.
REFERENCES
For additional information about getting help with Visual Basic for
Applications, please see the following article in the Microsoft Knowledge
Base:
163435 VBA: Programming Resources for Visual Basic for Applications
Modification Type: | Minor | Last Reviewed: | 10/10/2006 |
---|
Keywords: | kbdtacode kbprb kbProgramming KB172760 |
---|
|