WORKAROUND
Microsoft provides programming examples for illustration only, without warranty either expressed or implied. This includes, but is not limited to, the implied warranties of merchantability or fitness for a particular purpose. This article assumes that you are familiar with the programming language that is being demonstrated and with the tools that are used to create and to 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 requirements.
The following workarounds assume that you have a Visual Basic module that
contains two macros:
Sub Macro1()
Dim X As Variant
X = ActiveWorkbook.Sheets("Sheet1").Range("A1:A5")
Macro2 X(1, 1) 'X is an array of type Variant...
End Sub
Sub Macro2(Y As Integer) '...but Macro2 expects an Integer.
MsgBox Y
End Sub
When you run these macros, the first macro (Macro1) initializes an array named X, populates
the array, and then sends a value from the array to the second macro
(Macro2). Macro2 then displays the value in a message box. If you run
Macro1 without applying any of the following workarounds, you will receive
the error message described in the "Symptoms" section.
Method 1
To prevent the problem from occurring, change how the second macro (Macro2)
accepts values. In this case, change the second macro as follows:
Sub Macro2(Y As Variant) 'Y is now a Variant, not an Integer.
MsgBox Y
End Sub
This eliminates the problem because you are sending an element from an array of type
Variant to a variable of type
Variant.
Method 2
A second way to prevent the problem from occurring is to convert the value
to an
Integer as you pass it to the second macro using the
CInt function.
Sub Macro1()
Dim X As Variant
X = ActiveWorkbook.Sheets("Sheet1").Range("A1:A5")
Macro2 CInt(X(1, 1)) 'Convert Variant X(1, 1) using CInt
End Sub
Sub Macro2(Y As Integer) 'Macro2 expects an Integer.
MsgBox Y
End Sub
Method 3
Another way to prevent the problem from occurring is to dimension a second
variable in the first macro. This second variable should be of the same
type as the value accepted by the second macro. Copy the value from the array into the second variable, and then send it to the second macro.
For example:
Sub Macro1()
'Z is the second variable. It is an Integer, just like Y.
Dim X As Variant, Z As Integer
X = ActiveWorkbook.Sheets("Sheet1").Range("A1:A5")
Z = X(1, 1) 'Get the value from the array and put it in Z.
Macro2 Z 'This works correctly.
End Sub
Because Z is an integer, the value of Z is received by Macro2 (which expects an integer) correctly.