XL2000: Custom Function to Turn Nonadjacent Cells into an Array

Article translations Article translations
Article ID: 213403 - View products that this article applies to.
This article was previously published under Q213403
This article has been archived. It is offered "as is" and will no longer be updated.
Expand all | Collapse all

On This Page

Summary

In Microsoft Visual Basic for Applications, you can create a custom function that will turn a nonadjacent selection of cells into an array. This is useful with many of the built-in Microsoft Excel functions that require a single range or an array as input when the data on the worksheet is not contained in a contiguous range.

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

Sample Visual Basic Procedure

This MakeArray function can use any contiguous range of cells as its arguments. Nonadjacent ranges are separated by commas.
Function MakeArray(ParamArray CellAddress()) As Variant
   ' Declaration of function variables.
   Dim Temp As Variant
   Dim TheArray() As Variant
   Dim Count As Integer, Ver as Integer
   Dim W As Integer, X As Integer, Y As Integer, Z As Integer

   ' Initialize the Count variable.
   Count = 1
   ' Set the variable Ver = 0 if the version of Microsoft Excel is
   ' greater than 8 (8 is Microsoft Excel 97 for Windows).
   If Left(Application.Version, Len(Application.Version) - 1) >= 8 Then
      Ver = 0
   Else
      Ver = 1
   End If
   ' Set variable X from Ver to the total number of arguments in
   ' the CellAddress array.
   For X = Ver To UBound(CellAddress, 1)
      ' Temp equals the first element of the CellAddress array.
      Set Temp = CellAddress(X)

      ' Test Temp to see whether it is an array.
      If IsArray(Temp) Then

         ' If Temp is an array, set Y from 1 to the total number
         ' arguments in the Temp array's first dimension.
         For Y = 1 To UBound(Temp.Value, 1)
             ' If Temp is an array, set Z from 1 to the total number
            ' arguments in the Temp array's second dimension.
            For Z = 1 To UBound(Temp.Value, 2)

               ' ReDimension TheArray, Preserving any existing
               ' values, from 1 to Count.
               ReDim Preserve TheArray(1 To Count)

               ' TheArray, element Count equals Temp, element Y in the
               ' first dimension by element Z in the second dimension.
               TheArray(Count) = Temp(Y, Z).Value
                ' Increment the Count variable by one.
               Count = Count + 1
            Next Z

         Next Y
      ' If Temp is not an array, proceed from here.
      Else
         ' ReDimension TheArray, preserving any existing
         ' values, from 1 to Count.
         ReDim Preserve TheArray(1 To Count)
          ' TheArray element Count equals Temp.
         TheArray(Count) = Temp

         ' Increment the Count variable by one.
         Count = Count + 1
      ' End the block If statement.
      End If
   Next X
   ' Return TheArray to our function MakeArray.
   MakeArray = TheArray

End Function
				

Using The Sample Procedure

  1. Start a new Excel workbook and enter the following information in a worksheet:
          A1: 1   B1: 2     D1: 5
          A2: 3   B2: 4     D2: 6
    					
  2. Start the Visual Basic Editor (Press ALT+F11)
  3. On the Insert menu, click Module.
  4. Type the sample Visual Basic MakeArray function code (shown above) into the module.
  5. Return to the worksheet (Press ALT+F11)
  6. On the worksheet, select cells A4:F4, type the following formula into the Formula bar
    =MakeArray(A1:B2,D1:D2)
    and then press CTRL+SHIFT+ENTER to enter the formula as an array formula.
The result will resemble the following example:
   A4:1   B4:2   C4:3   D4:4   E4:5   F4:6
 
				

References

For more information about how to use the sample code in this article, click the article number below to view the article in the Microsoft Knowledge Base:
212536 OFF2000: How to Run Sample Code from Knowledge Base Articles
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: 213403 - Last Review: October 24, 2013 - Revision: 1.0
Applies to
  • Microsoft Excel 2000 Standard Edition
Keywords: 
kbnosurvey kbarchive kbdtacode kbhowto kbprogramming KB213403

Contact us for more help

Contact us for more help
Connect with Answer Desk for expert help.
Get more support from smallbusiness.support.microsoft.com