XL97: Returning Values from ListBox Displaying Multiple Columns

ID: Q165501


The information in this article applies to:
  • Microsoft Excel 97 for Windows


SUMMARY

You can display more than one column of data in a ListBox control on a UserForm. However, when you select an item from the list, only the value from the column that you are binding to is returned. This article provides an example of how to return multiple values from a ListBox that displays three columns of data.


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/overview/overview.asp
  1. Save and close any open workbooks, and then open a new workbook.


  2. On Sheet1, enter the following values:
    
        A1: Year  B1: Month     C1: Day
        A2: 1996  B2: February  C2: 23
        A3: 1997  B3: March     C3: 18
        A4: 1998  B4: September C4: 7
        A5: 1999  B5: November  C5: 3 


  3. Start the Visual Basic Editor (press ALT+F11).


  4. If the Properties Window is not visible, click Properties on the View menu (or press F4).


  5. On the Insert menu, click UserForm.


  6. Draw a ListBox control on the UserForm.


  7. Activate the Properties window (press F4).


  8. Change the following properties of the ListBox control to the following values:
    
        Property         Value
        ------------------------------
        BoundColumn       1
        ColumnCount       3
        ColumnHeads       True
        RowSource         Sheet1!A2:A5 


  9. Draw a Label control on the UserForm.


  10. Double-click the ListBox to open the code window for the ListBox.


  11. In the module type the following code for the ListBox Change event:
    
      Private Sub ListBox1_Change()
           Dim SourceData As Range
           Dim Val1 As String, Val2 As String, Val3 As String
    
           'Get Range that the ListBox is bound to
           Set SourceRange = Range(ListBox1.RowSource)
    
           Val1 = ListBox1.Value
           'Get the value of the second column
           Val2 = SourceRange.Offset(ListBox1.ListIndex, 1).Resize(1, 1).Value
           'Get the value of the third column
           Val3 = SourceRange.Offset(ListBox1.ListIndex, 2).Resize(1, 1).Value
    
           'Concatenate the three values together and display them in Label1
           Label1.Caption = Val1 & " " & Val2 & " " & Val3
         End Sub 


  12. Run the UserForm. To do this, activate the userform, and then click Run Sub/UserForm on the Run menu.


When you click an entry in the list box, the label will change to reflect all three of the columns in that entry.


REFERENCES

For more information about using the ListBox control, click the Office Assistant, type "listbox control" (without the quotation marks), click Search, and then click to view the "ListBox Control" topic.

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

Q120802 Office: How to Add/Remove a Single Office Program or Component

Additional query words: XL97 multi-column

Keywords : kbprg kbui kbdta KbVBA kbhowto
Version : WINDOWS:
Platform : WINDOWS
Issue type : kbhowto


Last Reviewed: November 9, 1999
© 2000 Microsoft Corporation. All rights reserved. Terms of Use.