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 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 Microsoft Advisory Services. For more information, visit these Microsoft Web sites:
Microsoft Certified Partners -
https://partner.microsoft.com/global/30000104Microsoft Advisory Services -
http://support.microsoft.com/gp/advisoryserviceFor more information about the support options that are available and about how to contact Microsoft, visit the following Microsoft Web site:
http://support.microsoft.com/default.aspx?scid=fh;EN-US;CNTACTMSMethod 1: Return a Variable-Size Result Array
This method returns an array of values based on an argument range. The size
of the resulting array varies, depending on the number of elements in
the argument array.
The sample custom function in the following example accepts an array (a range of values) as its argument, and then multiplies each value in the range by 100.
- Start Excel, and then create the following spreadsheet:
A1: 5
A2: 3
A3: 1
A4: 2
- Press ALT+F11 to start the Visual Basic Editor.
- On the Insert menu, click Module.
- In the module sheet, type the following custom function:
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
- Press ALT+F11 to return to Excel.
- Select the range B1:B4.
- Type the following formula in the formula bar:
=Multiply_Range(A1:A4)
- Press CTRL+SHIFT+ENTER to enter the formula as an array formula.
The formula returns the following results:
B1: 500
B2: 300
B3: 100
B4: 200
Method 2: Return a Fixed-Size Result Array
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 three-row by one-column array.
- Start Excel, and then create the following spreadsheet:
A1: 1:00:00
A2: 6:49:34
- Press ALT+F11 to start the Visual Basic Editor.
- On the Insert menu, click Module.
- In the module sheet, type the following custom function:
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
- Press ALT+F11 to return to Excel.
- Select three contiguous cells in a column (for example, A3:A5).
- Type the following formula in the formula bar:
=Elapsed_Time(A1,A2)
- Press CTRL+SHIFT+ENTER to enter the formula as an array formula.
The formula returns the following results:
A3: 5
A4: 49
A5: 34
NOTE: If you prefer to enter the function horizontally into a range of cells instead of vertically, change the Elapsed_Time line to read as follows:
Elapsed_Time = Array(hours, minutes, seconds)