XL2000: How to Return Multiple Values from a Custom Function

This article was previously published under Q213484
This article has been archived. It is offered "as is" and will no longer be updated.
Summary
In Microsoft Excel, there are two different methods that you can use to return multiple values from a custom function: One method returns a variable-sized array, and the other method returns a fixed-size array.

This article contains sample Microsoft Visual Basic for Applicationsprocedures that demonstrate each of these methods.
More information
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/30000104

Microsoft Advisory Services - http://support.microsoft.com/gp/advisoryservice

For 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;CNTACTMS

Method 1: Return a Variable-Size Result Array

This method returns an array of values based on an argument range. The sizeof the resulting array varies, depending on the number of elements inthe 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.
  1. Start Excel, and then create the following spreadsheet:
    A1: 5
    A2: 3
    A3: 1
    A4: 2
  2. Press ALT+F11 to start the Visual Basic Editor.
  3. On the Insert menu, click Module.
  4. 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 = tempEnd Function					
  5. Press ALT+F11 to return to Excel.
  6. Select the range B1:B4.
  7. Type the following formula in the formula bar:
    =Multiply_Range(A1:A4)
  8. 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 assumesthat 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.
  1. Start Excel, and then create the following spreadsheet:
    A1: 1:00:00
    A2: 6:49:34
  2. Press ALT+F11 to start the Visual Basic Editor.
  3. On the Insert menu, click Module.
  4. 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					
  5. Press ALT+F11 to return to Excel.
  6. Select three contiguous cells in a column (for example, A3:A5).
  7. Type the following formula in the formula bar:
    =Elapsed_Time(A1,A2)
  8. 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)
References
For more information about using arrays, in the Visual Basic Editor, click Microsoft Visual Basic Help on the Help menu, type using array in the Office Assistant or the Answer Wizard, and then click Search to view the topic.
udf XL2000
Note This is a "FAST PUBLISH" article created directly from within the Microsoft support organization. The information contained herein is provided as-is in response to emerging issues. As a result of the speed in making it available, the materials may include typographical errors and may be revised at any time without notice. See Terms of Use for other considerations.
Properties

Article ID: 213484 - Last Review: 10/25/2013 22:56:00 - Revision: 1.0

  • Microsoft Excel 2000 Standard Edition
  • kbnosurvey kbarchive kbdtacode kbhowto kbinfo kbprogramming KB213484
Feedback