XL97: #VALUE! Appears When Function Is Recalculated

Last reviewed: January 7, 1998
Article ID: Q175290
The information in this article applies to:
  • Microsoft Excel 97 for Windows

SYMPTOMS

In Microsoft Excel 97, cells that contain formulas that refer to user- defined functions may return a #VALUE! error after you run a Visual Basic for Applications macro or perform any action that causes the worksheet that contains the formulas to be recalculated.

Also, if a Visual Basic subroutine is running when the formulas are recalculated, the subroutine may stop without warning.

CAUSE

These problems may occur if an error occurs in a user-defined function while the worksheet is recalculated.

For an example of this problem, see the "More Information" section 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 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/default.asp

To work around this problem, press CTRL+ALT+F9 to force the values to be recalculated. When you do this, any formulas that refer to user-defined functions are recalculate correctly.

To prevent this problem from occurring, add error-handling code to your user-defined function, for example:

   Function MyFunction(CellRange As Object) As String
       On Error GoTo ErrorHandler                       'new line
       If CellRange.Interior.Pattern = xlNone Then
           MyFunction = "yes"
       Else
           MyFunction = "no"
       End If
       Exit Function                                    'new line
   ErrorHandler:                                        'new line
       MyFunction = "error"                             'new line
   End Function

In this user-defined function, the line "On Error GoTo ErrorHandler" causes the function to continue if an error occurs. In this case, the error- handling code causes the function to return a value of "error," instead of "yes" or "no." After the formulas return "error," press CTRL+ALT+F9 to recalculate the worksheet.

STATUS

Microsoft has confirmed this to be a problem in the Microsoft products listed at the beginning of this article. We are researching this problem and will post new information here in the Microsoft Knowledge Base as it becomes available.

MORE INFORMATION

In Microsoft Excel 97, if a user-defined function returns an error value, the formula that called the user-defined function and any other formulas that call the same user-defined function may fail to be recalculated properly. When this happens, the formulas may return a #VALUE! error.

Also, if the user-defined function returns an error value, any running Visual Basic subroutine that caused the recalculation to occur may stop. This may cause problems if the subroutine is running unattended.

To see examples of these problems, follow these steps:

  1. In Microsoft Excel 97, create a new workbook.

  2. On the Tools menu, point to Macro, and then click Visual Basic Editor. Then, click Module on the Insert menu.

  3. Enter the following code into the new module:

          Function MyFunction(CellRange As Object) As String
    

              'This line will fail when you delete a row from the worksheet.
              If CellRange.Interior.Pattern = xlNone Then
                  MyFunction = "yes"
              Else
                  MyFunction = "no"
              End If
          End Function
    
          Sub TestDelete()
              Rows(2).Delete              'Deleting a row forces
                                          'recalculation.
              MsgBox "Delete succeeded."
          End Sub
    
    

  4. On the File menu, click "Close and Return to Microsoft Excel."

  5. Select cells A10:A12 in the worksheet. Type the following formula

          =MyFunction(C10)
    

    and press CTRL+ENTER.

    All three cells (A10, A11, A12) display the value "yes."

  6. On the Tools menu, point to Macro, and click Macros. Select TestDelete, and then click Run.

    Note that the three cells (A9, A10, A11) display the #VALUE! error value. Note also that the message box in the TestDelete subroutine is not displayed.

  7. Press CTRL+ALT+F9.

The three formulas are recalculate correctly.

If you use the MyFunction function in the "Workaround" section, the formulas do not return a #VALUE! error value when you run the TestDelete subroutine, and the message box in TestDelete is displayed correctly. However, you still must press CTRL+ALT+F9 to force the formulas to display the correct value, which is "yes."


Additional query words: XL97
Keywords : xlformula xlvbainfo
Version : WINDOWS:97
Platform : WINDOWS
Issue type : kbprb
Solution Type : kbworkaround


THE INFORMATION PROVIDED IN THE MICROSOFT KNOWLEDGE BASE IS PROVIDED "AS IS" WITHOUT WARRANTY OF ANY KIND. MICROSOFT DISCLAIMS ALL WARRANTIES, EITHER EXPRESS OR IMPLIED, INCLUDING THE WARRANTIES OF MERCHANTABILITY AND FITNESS FOR A PARTICULAR PURPOSE. IN NO EVENT SHALL MICROSOFT CORPORATION OR ITS SUPPLIERS BE LIABLE FOR ANY DAMAGES WHATSOEVER INCLUDING DIRECT, INDIRECT, INCIDENTAL, CONSEQUENTIAL, LOSS OF BUSINESS PROFITS OR SPECIAL DAMAGES, EVEN IF MICROSOFT CORPORATION OR ITS SUPPLIERS HAVE BEEN ADVISED OF THE POSSIBILITY OF SUCH DAMAGES. SOME STATES DO NOT ALLOW THE EXCLUSION OR LIMITATION OF LIABILITY FOR CONSEQUENTIAL OR INCIDENTAL DAMAGES SO THE FOREGOING LIMITATION MAY NOT APPLY.

Last reviewed: January 7, 1998
© 1998 Microsoft Corporation. All rights reserved. Terms of Use.