XL97: Value Returned by VarType for Omitted Arguments DiffersLast reviewed: February 27, 1998Article ID: Q165103 |
The information in this article applies to:
SYMPTOMSWhen you call a custom Visual Basic for Applications function from a formula in a cell in a Microsoft Excel 97 worksheet, the VarType function may return different values for missing optional arguments than it does in earlier versions of Microsoft Excel. The IsMissing and IsNull functions may also return different results.
CAUSEThis problem occurs because the method Microsoft Excel 97 uses to send argument from worksheet formulas to Visual Basic for Applications functions is different from the method used by earlier versions of Microsoft Excel. NOTE: This problem does not occur when you use a Visual Basic for Applications subroutine to call a Visual Basic for Applications function.
RESOLUTIONMicrosoft provides examples of Visual Basic for Applications procedures 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. The Visual Basic procedures in this article are provided 'as is' and Microsoft does not guarantee that they can be used in all situations. While Microsoft support engineers can help explain the functionality of a particular macro, they will not modify these examples to provide added functionality, nor will they help you construct macros to meet your specific needs. If you have limited programming experience, you may want to consult one of the Microsoft Solution Providers. Solution Providers offer a wide range of fee-based services, including creating custom macros. For more information about Microsoft Solution Providers, call Microsoft Customer Information Service at (800) 426-9400. If the function uses the VarType, IsMissing, and/or IsNull functions to check the status of a missing argument, it may be necessary to modify the function to accommodate the change in behavior in Microsoft Excel 97. For example, if your function contains a line of code that is similar to the following
If VarType(X) = 10 Thenchange the line so that it accounts for a VarType of 1 (the default) in Microsoft Excel 97, for example:
If (VarType(X) = 10 And Application.Version < 8) Or (VarType(X) = 1 _ And Application.Version = 8) ThenThis line of code accounts for the difference in behavior between Microsoft Excel 97 and earlier versions of Microsoft Excel. You can use similar methods to correct any lines of code that uses the IsMissing and/or IsNull functions.
STATUSMicrosoft 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 INFORMATIONWhen you call a custom function from a formula in a worksheet cell, the value that is returned by VarType for missing optional arguments differs according to the version of Microsoft Excel that you are using. The values that are returned by VarType for different versions of Microsoft Excel are listed in the following table.
VarType Value for Microsoft Excel Missing Arguments Corresponds to ------------------------------------------------------------------- 97 1 (vbNull) IsNull(<variable>) = True IsMissing(<variable>) = False 5.0, 7.0 10 (vbError) IsMissing(<variable>) = True IsNull(<variable>) = FalseNOTE: This difference does NOT apply when you use a Visual Basic for Applications subroutine to call a custom function. If you omit arguments when you use a Visual Basic for Applications subroutine to call a custom function, the value that is returned by VarType for the missing arguments is 10 in all versions of Microsoft Excel (versions 5.0, 7.0, and Microsoft Excel 97). The following example demonstrates the change in behavior for the VarType function:
Cell Microsoft Excel 97 Microsoft Excel 5.0, 7.0 Different --------------------------------------------------------------------- A1 IsMissing = False, False IsMissing = False, False No IsNull = False, False IsNull = False, False No VarType = 5, 5 VarType = 5, 5 No A2 IsMissing = False, False IsMissing = True, False Yes IsNull = True, False IsNull = False, False Yes VarType = 1, 5 VarType = 10, 5 Yes A3 IsMissing = False, False IsMissing = False, True Yes IsNull = False, True IsNull = False, False Yes VarType = 5, 1 VarType = 5, 10 Yes A4 IsMissing = False, False IsMissing = True, True Yes IsNull = True, True IsNull = False, False Yes VarType = 1, 1 VarType = 10, 10 YesMicrosoft Excel 97 reports missing arguments as null values because the value that is returned by VarType for these arguments is 1. In earlier versions of Microsoft Excel, the missing arguments are reported as error values because the value that is returned by VarType is 10. If you run the TestProc macro, the four message boxes that appear are identical in all versions of Microsoft Excel (5.0, 7.0, and Microsoft Excel 97). If you omit arguments when you call a Visual Basic for Applications function from a macro, the value returned by VarType for the missing arguments is always 10.
|
Additional query words: 97 XL97 xl97vbmigrate
© 1998 Microsoft Corporation. All rights reserved. Terms of Use. |