XL98: How to Fill a ListBox Control with Multiple Ranges (183183)



The information in this article applies to:

  • Microsoft Excel 98 Macintosh Edition

This article was previously published under Q183183
kbclone: Q213746, Q161534

SUMMARY

This article contains an example that fills the list of a ListBox control on a UserForm with data from multiple cell ranges.

MORE INFORMATION

To fill a ListBox with values from multiple cell ranges, you must loop through the various ranges with a Visual Basic for Applications procedure and add the items to the list one at a time.

The following examples populate a ListBox control as it is loaded by using the Initialize event for the UserForm.

Microsoft provides programming examples for illustration only, without warranty either expressed or implied. This includes, but is not limited to, the implied warranties of merchantability or fitness for a particular purpose. This article assumes that you are familiar with the programming language that is being demonstrated and with the tools that are used to create and to 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 requirements.

Populating the ListBox Directly from Worksheet Cells

To populate the ListBox, follow these steps:
  1. Close and save any open workbooks and then create a new workbook.
  2. On Sheet1, enter the following values:
          A1: Planes        C1: Alpha
          A2: Trains        C2: Bravo
          A3: Automobiles   C3: Charlie
  3. Start the Visual Basic Editor (press OPTION+F11).
  4. On the Insert menu, click UserForm.
  5. Draw a ListBox control on the UserForm.
  6. Double-click the UserForm to open the Code window for the UserForm.
  7. In the module type the following code for the UserForm Initialize event:
          Private Sub UserForm_Intialize()
              Dim Lrange As Range
              Dim x As Variant
    
              ' Set the range to loop through.
              Set Lrange = Union(Sheet1.Range("A1:A3"), Sheet1.Range("C1:C3"))
    
              ' Loops through the ranges.
              For Each x In Lrange
    
                  ' Adds an item to the list.
                  Listbox1.AddItem x.Value
    
              Next x
    
          End Sub
    						
  8. Run the UserForm.

    The items in the ranges A1:A3 and C1:C3 on Sheet1 are added to the list in ListBox1.
  9. Close the UserForm.

Using an Array to Populate the ListBox

It is also possible to assign the contents of a Visual Basic array as the list of a ListBox control. The following example reads the values from the worksheet into an array, and then assigns the array to the ListBox control as the list:
  1. In the module, change the code for the UserForm Initialize event:
          Private Sub UserForm_Initialize()
              Dim Lrange As Range
              Dim Larray() As Variant
              Dim x As Variant
              Dim ctr As Integer
    
              ' Set the range to loop through.
              Set Lrange = Union(Sheet1.Range("A1:A3"), Sheet1.Range("C1:C3"))
    
              ' Loops through the ranges.
              For Each x In Lrange
    
                  ReDim Preserve Larray(ctr)
    
                  ' Add an item to the array.
                  Larray(ctr) = x.Value
    
                  ctr = ctr + 1
    
              Next x
    
              ' Assign the array to the listbox.
              ListBox1.List = LArray
    
          End Sub
    						
  2. Run the UserForm.

    The items in the ranges A1:A3 and C1:C3 on Sheet1 are read into an array and are then assigned to the list of ListBox1.
  3. Close the UserForm.

REFERENCES

For additional information about populating list boxes in earlier versions of Microsoft Excel, please see the following article here in the Microsoft Knowledge Base:

153603 XL: Macro to Fill a List Box with Multiple Ranges

For more information about ListBox Controls, click the Office Assistant while in the Visual Basic Editor, type listbox, click Search, and then click to view "ListBox control."

NOTE: If the Assistant is hidden, click the Office Assistant button on the Standard toolbar. If Microsoft Help is not installed on your computer, please see the following article in the Microsoft Knowledge Base:

179216 OFF98: How to Use the Microsoft Office Installer Program


Modification Type:MajorLast Reviewed:6/17/2005
Keywords:kbhowto kbProgramming KB183183