XL: Function Using ActiveCell Property Returns Incorrect Result

ID: Q172760


The information in this article applies to:
  • Microsoft Excel 98 Macintosh Edition
  • Microsoft Excel 97 for Windows
  • Microsoft Excel for Windows 95, versions 7.0, 7.0a
  • Microsoft Excel for Windows, versions 5.0, 5.0c
  • Microsoft Excel for the Macintosh, versions 5.0, 5.0a


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.


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 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/support/supportnet/overview/overview.asp
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.


MORE INFORMATION

When 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:

  1. In Microsoft Excel, create a new workbook.


  2. In Sheet1 of the new workbook, enter the following values:
    A1: 1
    A2: 2
    A3: 3
    A4: 4
    A5: 5


  3. Insert a new Visual Basic module. (In Microsoft Excel 97 or Microsoft Excel 98, first activate the Visual Basic Editor by pressing ALT+F11.) Type the following code into the new module:
    
          Function Test()
             Application.Volatile
             Test = ActiveCell.Offset(0, -1).Value
          End Function 


  4. Switch to Sheet1. Enter the following formula into cell B1:
    
          =Test() 
    Note that the formula returns the value 1. This is the correct value because the cell that is one column to the left of the active cell (B1) contains the value 1.


  5. Select cell B1. On the Edit menu, click Copy. Select cells B2:B5. On the Edit menu, click Paste, and then press ESC.

    Note that all five formulas in B1:B5 return the value 2. This is true because the cell that is one column to the left of the active cell (B2) contains the value 2.


  6. Select cell D10. Press F9.

    All five formulas in B1:B5 return the value 0, because the cell that is one column to the left of the active cell (D10) contains no value, which is equivalent to having a value of 0.


  7. If you want the function to always return the value of the cell that is one column to the left of the cell that is calling the function, change the function to the following:
    
          Function Test()
              Application.Volatile
              Test = Application.Caller.Offset(0, -1).Value
          End Function 
    When you change the function, and then recalculate the worksheet, the formulas in B1:B5 return the values 1 through 5 no matter what cell or worksheet is active.



REFERENCES

For additional information about getting help with Visual Basic for Applications, please see the following article in the Microsoft Knowledge Base:

Q163435 VBA: Programming Resources for Visual Basic for Applications

Additional query words: XL5 XL7 XL97 XL98

Keywords : kbprg kbdta kbdtacode xlformula KbVBA
Version : MACINTOSH:5.0,5.0a,98; WINDOWS:5.0,5.0c,7.0,7.0a,97
Platform : MACINTOSH WINDOWS
Issue type : kbprb


Last Reviewed: November 9, 1999
© 2000 Microsoft Corporation. All rights reserved. Terms of Use.