XL: Function Using ActiveCell Property Returns Incorrect ResultLast reviewed: February 3, 1998Article ID: Q172760 |
The information in this article applies to:
SYMPTOMSWhen 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.
CAUSEThis problem occurs when the following conditions are true:
WORKAROUNDMicrosoft 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 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 needs. If you have limited programming experience, you may want to contact the Microsoft fee-based consulting line at (800) 936-5200. For more information about the support options available from Microsoft, please see the following page on the World Wide Web:
http://www.microsoft.com/supportnet/refguide/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 Functionchange 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 FunctionWhen you do this, the function correctly uses the cell that is calling the function instead of using the currently active cell.
STATUSThis behavior is by design of the versions of Microsoft Excel listed at the beginning of this article.
MORE INFORMATIONWhen you use the ActiveCell property in a custom function in Microsoft Excel, the property returns the cell that is currently active. This is true even if the custom function is called by a formula in a worksheet cell. The Caller property of the Application object returns the object that calls the function, regardless of the cell or worksheet that is active. To demonstrate the problem described in this article, follow these steps:
REFERENCESFor additional information about getting help with Visual Basic for Applications, please see the following article in the Microsoft Knowledge Base:
ARTICLE-ID: Q163435 TITLE : VBA: Programming Resources for Visual Basic for Applications |
Additional query words: XL5 XL7 XL97 XL98
© 1998 Microsoft Corporation. All rights reserved. Terms of Use. |