This blog post shows you how to manipulate List Boxes (form controls) manually and with vba code.

The list box shows you a number of values with a scroll bar (if needed).  Selected value is Asia and it is the fourth (4) value in list F1:F6. It links the relative position of selected value (4) in a list, here it is linked to cell D2.

list box overview

Form controls are not as flexible as ActiveX controls but are compatible with earlier versions of Excel. You can find the controls on the developer tab.
How to enable developer tab: Excel 2007, Excel 2010 and Excel 2013

Table of Contents

  1. Create a List Box
  2. Assign macro to a List Box
  3. Add values to a List Box
  4. Link List Box to a cell
  5. Delete values in a List Box
  6. Set default value to a List Box
  7. Allow multiple selected values in a List Box
  8. Read selected values

Create a List Box

Steps to build a List Box:

  1. Go to tab "Developer" on the ribbon.
  2. Click "Insert" button.
    list box on the ribbon
  3. Click List Box button.
  4. Click and hold and then drag with mouse on sheet.
    list box on a sheet

You can build a List Box with vba code, here is how:

Sub Macro2()
'Worksheets("Sheet1").ListBoxes.Add(Left, Top, Width, Height)
Worksheets("Sheet1").ListBoxes.Add(100, 50, 96.75, 32.25).Name = "List box 100"
End Sub

list box vba code

Assign macro to List Box

  1. Right click with mouse on list box.
    list box assign macro
  2. Click "Assign macro...".
  3. Select a macro in the list.
  4. Click OK.

You can assign macro to a List Box by using vba code.

Sub Macro3()
Worksheets("Sheet1").Shapes("List box 100").OnAction = "Macro2"
End Sub

Add values to a List Box

You can add values to a List box with these steps:

  1. Right click on List Box
  2. Click "Format Control..."
  3. Go to tab "Control"
  4. Select an Input range.
    list box add values
  5. Click OK

The following vba macro adds E1:E3 to the List Box input range.

Sub PopulateListBox2()
Worksheets("Sheet1").Shapes("List Box 100").ControlFormat.ListFillRange = _
"E1:E3"
End Sub

The vba macro below adds the values in cell range E1:E3 to "List Box 100" without manipulating the input range. I recommend using the macro above, if values change in cell range E1:E3 they are instantly changed in List Box also. On the other hand, you can´t delete specific values using a vba macro.

Sub PopulateListBox()
Worksheets("Sheet1").Shapes("List Box 100").ControlFormat.List = _
Worksheets("Sheet1").Range("E1:E3").Value
End Sub

If your cell range size often changes, consider using a named range. Use technique demonstrated here: Populate combox with values from a dynamic named range

You can also populate a List Box with excel table values:
Populate combox with values from a table

Link List Box to a cell

  1. Right click on List Box
  2. Click "Format Control..."
  3. Go to tab "Control"
  4. Select a cell to link.
    pic
  5. Click OK
Sub LinkCell()
Worksheets("Sheet1").Shapes("List box 100").ControlFormat.LinkedCell = "A1"
End Sub
Sub LinkCell2()
With Worksheets("Sheet1").Shapes("List box 100").ControlFormat
Worksheets("Sheet1").Range("B1").Value = .List(.ListIndex)
End With
End Sub

Delete values in a List box

The following macro deletes all values in "List Box 100". It also removes the cell reference in "Input range:"

The RemoveItem method cannot be used to remove items from a list box if the list box is linked to a range on a worksheet.

You will get this error messages: Run-time error '1004': RemoveItem method of ListBox class failed.

Sub RemoveAllItems()
Worksheets("Sheet1").Shapes("List Box 100").ControlFormat.RemoveAllItems
End Sub

This macro deletes first value in "List Box 100".

Sub RemoveAllItems()
Worksheets("Sheet1").Shapes("List box 100").ControlFormat.RemoveItem 1
End Sub

Set default value in a List Box

This macro sets default value to the first value in a List Box.

list box change default value

Sub ChangeSelectedValue()
Worksheets("Sheet1").ListBoxes("List box 100").Selected = 1
End Sub

Allow multiple selected values in a List Box

  1. Right click on List Box.
  2. Click "Format Control...".
  3. Go to tab Control.
  4. Click Multi in "Selection type" window.
    list box multi
  5. Click OK button.

list box allow multiple values

This macro enables "Multi" for List Box 100.

Sub Allowmultiselect()
Worksheets("Sheet1").ListBoxes("List box 100").MultiSelect = xlSimple
End Sub

Read selected value(s)

This macro returns the relative position of all selected values.

Sub ReadSelectedValue()
With Worksheets("Sheet1").ListBoxes("List box 100")
For i = 1 To .ListCount
If .Selected(i) Then MsgBox i
Next i
End With
End Sub

If you prefer, you can return the selected value with .List(.ListIndex) property.

Sub ReadSelectedValue()
With Worksheets("Sheet1").ListBoxes("List box 100")
For i = 1 To .ListCount
If .Selected(i) Then MsgBox .List(.ListIndex)
Next i
End With
End Sub

Download excel *.xlsm file

Working with list boxes.xlsm