XL: Determining Which Items Are Selected in a List Box

Last reviewed: February 20, 1998
Article ID: Q111564

The information in this article applies to:

  • Microsoft Excel for Windows, versions 5.0, 5.0c
  • Microsoft Excel for Windows 95, versions 7.0, 7.0a
  • Microsoft Excel 97 for Windows
  • Microsoft Excel for the Macintosh, versions 5.0, 5.0a
  • Microsoft Excel 98 Macintosh Edition

SUMMARY

In Microsoft Excel, you can determine which items in a multi-selection list box are selected by using the Selected property of the list box. This article contains an example of how this can be done with a Microsoft Visual Basic for Applications procedure.

MORE INFORMATION

In a custom dialog box, a multi-selection list box allows you to choose any number of items from a list. For example, if a list contains Alpha, Bravo, and Charlie, you can select any, none, or all of those items.

To determine which items are selected, you can use the Selected property of the list box. The Selected property of a multi-selection list box is an array of values: each value is either True, if the item is selected, or False, if the item is not selected. For example, if the list contains 1, 2, 3, and 4, and 2 and 3 are selected, the Selected property would be the following array

   False, True, True, False

because the first item (1) is not selected, the second and third items (2 and 3) are selected, and the fourth item (4) is not selected.

An example of how to read the Selected array in a Visual Basic procedure is shown below.

Visual Basic Code Example

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

To create the procedure, follow these steps:

  1. In a new workbook, insert a new worksheet (Sheet1), a dialog sheet (Dialog1), and a Visual Basic module (Module1).

  2. On the worksheet, enter the following values:

          A1: Alpha
          A2: Bravo
          A3: Charlie
          A4: Delta
          A5: Echo
          A6: Foxtrot
          A7: Golf
          A8: Hotel
    

  3. On the dialog sheet, add an OK button that is set to dismiss the dialog box.

  4. On the dialog sheet, do the following to add a multi selection list box ("List1") that is linked to Sheet1!$A$1:$A$8.

    a. On the Forms toolbar, choose the List Box button. Drag on the dialog

          frame to create a list box.
    

    b. Select the list box.

    c. In the Name box, type "List1" (without the quotation marks) and

          press the ENTER key.
    

    d. From the Format menu, choose Object.

    e. Select the Control tab.

    f. In the Input Range box, type "Sheet1!$A$1:$A$8" (without the

          quotation marks).
    

    g. Under Selection Type, select the Multi option.

    h. Choose OK to accept the change.

    The list box is now linked to Sheet1!$A$1:$A$8 and is a multi selection list box.

  5. In Module1, enter the following:

       '----------------------------------------------------------------------
       Sub ShowSelectedItems()
    
          ' Dimension variables.
          Dim CurList As ListBox, Chosen As Integer
          Dim LTemp As Variant, LItem As Variant
          Dim Counter As Integer, MsgBoxText As String
    
          ' Set an object name for the list box to make it
          ' easier to reference.
          Set CurList = _
            DialogSheets("Dialog1").ListBoxes("List1")
    
          ' Initialize the list so that none of the items are
          ' selected.
          CurList.Selected = _
            Array(False, False, False, False, False, False, False, False)
    
          ' Show the dialog box and set variable 'chosen' to
          ' the value returned by the dialog box.
          chosen = DialogSheets("Dialog1").Show
    
          ' If cancel is chosen, exit the procedure.
          If chosen = 0 Then GoTo canceled
    
          ' Set the variable LTemp equal to the array of values
          ' indicating the selection state of the list box items.
          LTemp = CurList.Selected
    
          ' Initialize the Counter variable.
          Counter = 1
    
          ' Iterate through the loop once for each item in the
          ' array (which is the same as iterating once for each
          ' item in the list box).
          For Each LItem In LTemp
    
          ' If the value of the current item is True...
          If LItem = True Then
    
             ' Add text to the MsgBoxText variable indicating
             ' that the item is selected.
             ' CurList.List(Counter) returns the text of the selected item
             ' ("Alpha", "Bravo", and so on).
             MsgBoxText = MsgBoxText & CurList.List(Counter) & _
               " is selected. " & Chr(13)
    
          ' Otherwise...
          Else
    
             ' Add text to the MsgBoxText variable indicating that
             ' the item is not selected.
             ' CurList.List(Counter) returns the text of the unselected item
             ' ("Alpha", "Bravo", and so on).
             MsgBoxText = MsgBoxText & CurList.List(Counter) & _
               " is NOT selected. " & Chr(13)
    
          End If
    
          ' Increment the Counter so we can get the value of the
          ' next selected item.
          Counter = Counter + 1
    
          ' Repeat until all the items in the list have
          ' been checked.
          Next
    
          ' Display a dialog box indicating the selection state
          ' of each item in the list.
          MsgBox MsgBoxText
    
       ' If the Cancel button was chosen, exit procedure.
       canceled:
    
       End Sub
       '----------------------------------------------------------------------
    
    

  6. To run the subroutine, position the insertion point anywhere in the procedure, and either press F5 or click Start on the Run menu.

  7. When the dialog box is displayed, select one or more items in the list box, and choose the OK button.

A dialog box is displayed that indicates for each item in the list whether it was selected or not.

Note that you can modify this example and substitute any functions that perform a desired task using the selection state of the list items. For example, you might want to insert the current list item into a cell on a worksheet. To do this, you could use the following command

   Sheets("Sheet1").Cells(10, 10).Value = CurList.List(Counter)

to put the current list item into cell J10 on Sheet1.


Additional query words: 7.00 5.00 5.00c howto multiple dropdown XL98 XL97
XL7 XL5
Keywords : kbcode kbprg PgmHowto
Version : WINDOWS: 5.0, 5.0c, 7.0; MACINTOSH: 5.0, 5.0a
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 20, 1998
© 1998 Microsoft Corporation. All rights reserved. Terms of Use.