XL: How to Populate an Array with a Discontiguous Range

ID: Q149831

The information in this article applies to:

SUMMARY

To populate an array using Microsoft Visual Basic for Applications in Microsoft Excel, you need to iterate through the range object to populate an array with the data if the range object is discontiguous (whether it is a selection, range name, or the reference).

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 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/

When the range is contiguous, there is no need to iterate through the range. The following Visual Basic macro code includes an example of how you can iterate through a discontiguous range of data to populate an array and an example of how you can use a contiguous range of data to populate an array.

To use the sample macro code, follow these steps:

1. Open a new workbook and insert a Visual Basic module sheet.

2. On the module sheet, type the following macro code:

      Sub PopulateArrayThroughIteration()

          ' Dimension the variables.
          Dim MyArray() As Integer
          Dim cell As Object
          Dim counter As Integer

          ' Set the value of the counter variable.
          counter = 1

          ' Start the loop on the range.
          For Each cell In Range("a1,a3:a20")

              ' Redimension the array, while preserving the previous
              ' elements using the counter variable.
              ReDim Preserve MyArray(counter)
              ' Place a value into the array.
              MyArray(counter) = cell.Value
              ' Increase counter by 1.
              counter = counter + 1
          ' Loop.
          Next cell

          ' Check a value to make sure the array is populated
          ' this should return 5.
          MsgBox MyArray(4)

      End Sub

3. On Sheet1, type the numbers 1 to 20 in the range A1:A20.

4. Activate Sheet1.

5. Run the macro. To do this, use the following steps:

   a. On the Tools menu, click Macro. 

      -or-

      On the Tools menu, point to Macro, and then click Macros.

   b. In the Macro dialog box, select the name of the macro, and then click
      Run.

The following macro populates an array from a contiguous range of data.

   Sub PopulateArrayContiguous()
       Dim MyArray As Variant

       ' Populate the array.
       MyArray = Range("a1:a20")

       ' Display a message box with a value in the array
       ' this should display a 5.
       MsgBox MyArray(5, 1)

   End Sub

REFERENCES

"Visual Basic User's Guide," version 5.0, Chapter 6, "Working with Visual Basic Code in Procedures"

For more information about looping in Microsoft Excel version 7.0, click Answer Wizard on the Help menu, and type the following:

   For Each

For more information about looping in Microsoft Excel version 5.0, click the Search button in Help and type:

   For Each

Additional query words: 5.00 5.00a 5.00c 5.0 5.0c 7.00 7.00a XL98 XL97 XL7 XL5
Keywords          : kbprg kbdta kbdtacode PgmHowto KbVBA 
Version           : WINDOWS:5.x,7.0,97; MACINTOSH:5.0,5.0a,98
Platform          : MACINTOSH WINDOWS
Issue type        : kbhowto

Last Reviewed: May 18, 1999