XL: Using Calculate Method May Not Calculate Certain Formulas

ID: Q144508


The information in this article applies to:
  • Microsoft Excel for Windows 95, version 7.0
  • Microsoft Excel 97 for Windows


SYMPTOMS

When you calculate values on a worksheet, formulas that refer to cells that contain custom functions may not be calculated correctly.


CAUSE

This problem may occur if the following conditions are true:

  • A cell on the worksheet contains a custom function.

    -and-


  • A cell on the worksheet contains a formula that refers to the cell with the custom function.

    -and-


  • The calculation mode is set to Manual (click Options on the Tools menu and click the Calculation tab).

    -and-


  • You use a Visual Basic for Applications macro to calculate the cell that contains the custom function.

    -and-


  • The Visual Basic statement that you use to calculate the cell that contains the custom function uses the following syntax:

    Range("A1").Calculate

    NOTE: For the previous statement, assume that cell A1 contains the custom function.

    -and-


  • You manually recalculate the entire worksheet.



RESOLUTION

To correct this problem, obtain Microsoft Excel 97 Service Release 2 (SR-2).

For additional information about SR-2, please see the following article in the Microsoft Knowledge Base:

Q151261 : OFF97: How to Obtain and Install MS Office SR-2

To temporarily work around this problem, use one of the following methods.

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

Method 1

Make the custom function volatile. To do this, add the following line of code to the custom function:


   Application.Volatile 


NOTE: A volatile function is recalculated every time that the worksheet is recalculated. Making your custom function volatile may decrease the performance of your worksheet.

Method 2

Add to any formula that refers to a cell that contains a custom function. To do this, add the following to the formula:


   +(NOW()*0) 


For example, if your worksheet contains a custom function in cell A1, and cell B1 contains the following formula


   =A1 


change the formula in cell B1 to the following:


   =A1+(NOW()*0) 


NOTE: When you make this change to the formula in cell B1, cell B1 is recalculated every time that the worksheet is recalculated.

Method 3

Press CTRL+ALT+F9 to recalculate the values in the entire workbook.


STATUS

Microsoft has confirmed this to be a problem in the Microsoft products listed at the beginning of this article.


MORE INFORMATION

Example

To see an example of the problem described in the "Symptoms" section in this article, follow these steps:

  1. Save and close any open workbooks, and then create a new workbook.


  2. Start the Visual Basic Editor (press ALT+F11).


  3. On the Insert menu, click Module.


  4. Type the following code into the module sheet:
    
           Function Test() As Long
    
              Static i As Long
    
              Test = i
    
              i = i + 1
    
           End Function
    
           Sub Calc_Custom_Function()
    
              Range("A1").Calculate
    
           End Sub 


  5. Press ALT+F11 to return to Microsoft Excel.


  6. Type the following formula into cell A1 of Sheet1:

    =Test()


  7. Type the following formula into cell B1 of Sheet1:

    =A1


  8. Run the Calc_Custom_Function macro several times.


  9. Press F9 to calculate the values in the worksheet.

    Cells A1 and B1 are updated.


  10. Run the Calc_Custom_Function macro several times.


  11. Press F9 to calculate the values in the worksheet.


Cell A1 is updated as you expect, but cell B1 is not updated.

Additional query words: XL97 XL7 recalc

Keywords : kbprg kbdta kbdtacode xlformula
Version :
Platform :
Issue type : kbbug


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