XL97: Cells That Contain User-Defined Functions Not Recalculated, Return #Value (244466)
The information in this article applies to:
- Microsoft Excel 97 for Windows
This article was previously published under Q244466 SYMPTOMS
When you recalculate a worksheet, cells that contain user-defined functions are not recalculated and return #Value.
CAUSE
This problem occurs when the following conditions are true:
- The recalculation is invoked by means of the Calculate method.
- An untrapped run-time error occurs in a user-defined function (UDF) while recalculating a cell.
When the run-time error occurs, Excel stops the recalculation for the worksheet. All cells that have not been updated and are referencing the UDF returns #Value.
However, when you update the sheet by pressing the F9, only the cells in which the run-time error occurred returns #Value.
RESOLUTIONWORKAROUNDMicrosoft 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 a Microsoft Certified Partner or the Microsoft fee-based
consulting line at (800) 936-5200. For more information about Microsoft Certified
Partners, please visit the following Microsoft Web site:
For more information about the support options that are available and about how to contact Microsoft, visit the following Microsoft Web site:
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 recalculated 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
' You may want to use the following statement
' to output the type of error result instead
' of a string result.
'MyFunction = CVErr(xlErrValue)
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.
STATUSMicrosoft has confirmed that this is a problem in the Microsoft products that are listed at the beginning of this article.
Modification Type: | Minor | Last Reviewed: | 10/17/2005 |
---|
Keywords: | kbHotfixServer kbQFE kbbug kbfix kbQFE KB244466 |
---|
|