XL: Custom Function to Transpose Nonadjacent Range

Last reviewed: February 3, 1998
Article ID: Q134406
The information in this article applies to:
  • Microsoft Excel for Windows, versions 5.0, 5.0c
  • Microsoft Excel for Windows NT, version 5.0
  • Microsoft Excel for the Macintosh, versions 5.0, 5.0a
  • Microsoft Excel for Windows 95, version 7.0
  • Microsoft Excel 97 for Windows
  • Microsoft Excel 98 Macintosh Edition

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 beneficial with many of the built-in Microsoft Excel functions that require a single range or an array as input and 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 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 needs. If you have limited programming experience, you may want to contact the Microsoft fee-based consulting line at (800) 936-5200. For more information about the support options available from Microsoft, please see the following page on the World Wide Web:

   http://www.microsoft.com/support/supportnet/refguide/default.asp

This function takes any contiguous range of cells as its arguments. Nonadjacent ranges are separated by commas.

Sample Visual Basic Procedure

   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

To Use This Example

  1. Enter the following information in a worksheet:

          A1: 1   B1: 2   C1: <empty>   D1: 5
          A2: 3   B2: 4   C2: <empty>   D2: 6
    
    

  2. On the worksheet, select cells A4:F4, and type the following formula:

          =MakeArray(A1:B2,D1:D2)
    

    NOTE: The above formula must be entered as an array formula. To enter a formula as an array formula in Microsoft Excel for Windows, press CTRL+SHIFT+ENTER. In Microsoft Excel for the Macintosh, press COMMAND+ENTER.

The resulting formula will resemble the following example:

   A4:1   B4:2   C4:3   D4:4   E4:5   F4:6


Additional query words: XL97 5.00 5.00a 5.00c 7.00 8.00 discontiguous
noncontiguous
Keywords : kbcode kbprg PgmHowto
Version : WINDOWS: 5.0,5.0c,7.0,97; MACINTOSH: 5.0,5.0a,98
Platform : MACINTOSH WINDOWS
Issue type : kbhowto


THE INFORMATION PROVIDED IN THE MICROSOFT KNOWLEDGE BASE IS PROVIDED "AS IS" WITHOUT WARRANTY OF ANY KIND. MICROSOFT DISCLAIMS ALL WARRANTIES, EITHER EXPRESS OR IMPLIED, INCLUDING THE WARRANTIES OF MERCHANTABILITY AND FITNESS FOR A PARTICULAR PURPOSE. IN NO EVENT SHALL MICROSOFT CORPORATION OR ITS SUPPLIERS BE LIABLE FOR ANY DAMAGES WHATSOEVER INCLUDING DIRECT, INDIRECT, INCIDENTAL, CONSEQUENTIAL, LOSS OF BUSINESS PROFITS OR SPECIAL DAMAGES, EVEN IF MICROSOFT CORPORATION OR ITS SUPPLIERS HAVE BEEN ADVISED OF THE POSSIBILITY OF SUCH DAMAGES. SOME STATES DO NOT ALLOW THE EXCLUSION OR LIMITATION OF LIABILITY FOR CONSEQUENTIAL OR INCIDENTAL DAMAGES SO THE FOREGOING LIMITATION MAY NOT APPLY.

Last reviewed: February 3, 1998
© 1998 Microsoft Corporation. All rights reserved. Terms of Use.