MORE INFORMATION
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.
Method to Return a Variable-Size Result Array
This method returns an array of values based on an argument range. The size
of the resulting array fluctuates depending on the number of elements in
the argument array. For example, assume that you want to create a function
that multiplies each value in a range by 100. The following custom function
accepts an array (a range of values) as its argument:
Function Multiply_Range(myrange As Object) As Variant
Dim temp As Variant
Dim i As Integer, j As Integer
temp = myrange.Value 'creates a copy of the values in myrange
' if more than one element then loop through both dimensions of
' the array and multiply each element by 100.
' if not more than one element then temp is multiplied by 100.
If IsArray(temp) Then
For i = 1 To UBound(temp, 1)
For j = 1 To UBound(temp, 2)
temp(i, j) = temp(i, j) * 100
Next j
Next i
Else
temp = temp * 100
End If
Multiply_Range = temp
End Function
To use the custom function, enter the following data in cells A1:A4:
A1: 5
A2: 3
A3: 1
A4: 2
Select the range B1:B4 and enter the following formula as an array:
NOTE: The above formula must be entered as an array formula. To enter a
formula as an array formula, press COMMAND+ENTER.
The result will be:
A1: 5 B1: 500
A2: 3 B2: 300
A3: 1 B3: 100
A4: 2 B4: 200
Method to Return Array Result of a Fixed Size
This method for returning multiple values from a custom function assumes
that you have a fixed number of elements in the resulting array.
The following custom function accepts a starting time and an ending time
and returns the number of hours, minutes, and seconds between them in a 3-
row by 1-column array.
Function Elapsed_Time(start, finish As Date) As Variant
Dim hours, minutes, seconds As Integer
hours = Hour(finish - start)
minutes = Minute(finish - start)
seconds = Second(finish - start)
Elapsed_Time = Application.Transpose(Array(hours, minutes, seconds))
End Function
To use this custom function, enter a starting time and a finish time in
two cells (for example, A1 and A2 below).
A1: 1:00:00
A2: 6:49:34
Then, highlight three cells in a column (for example, A3 through A5) and
enter the following as an array formula:
NOTE: The above formula must be entered as an array formula. To enter a
formula as an array formula, press COMMAND+ENTER.
The result will appear as follows:
A1: 1:00:00
A2: 6:49:34
A3: 5
A4: 49
A5: 34
If you prefer to enter the function horizontally into a range of cells
instead of vertically, change the Elapsed_Time line to read:
Elapsed_Time = Array(hours, minutes, seconds)
REFERENCES
For more information about Arrays, from the Visual Basic Editor,
click the Office Assistant, type
array, click Search, and then click to
view "Using Arrays."
NOTE: If the Assistant is hidden, click the Office Assistant button on the
Standard toolbar. If the Assistant is not able to answer your query, please
see the following article in the Microsoft Knowledge Base:
176476 OFF: Office Assistant Not Answering Visual Basic Questions
For additional information about getting help with Visual Basic for
Applications, please see the following article in the Microsoft Knowledge
Base:
163435 VBA: Programming Resources for Visual Basic for Applications