Using ListBox Selections to Filter

Craig_1968

New Member
Joined
Oct 18, 2018
Messages
4
I've created a ListBox with multiple selections, i.e.APS2, APS3, APS4, APS5, APS6, EL1, EL2 and ELPAPP. I'd like to filter Sheet3,Column D according to the levels selected. Can anyone help with coding?



 

Excel Facts

Why does 9 mean SUM in SUBTOTAL?
It is because Sum is the 9th alphabetically in Average, Count, CountA, Max, Min, Product, StDev.S, StDev.P, Sum, VAR.S, VAR.P.
Is the listbox on a userform?

In userform code
Code:
Private Sub [COLOR=#ff0000]CommandButton1[/COLOR]_Click()
    Dim i As Integer, count As Integer, arr() As Variant
[COLOR=#006400][I]'create array of selected items[/I][/COLOR]
    With [COLOR=#ff0000]ListBox1[/COLOR]
        count = 0
        For i = 0 To .ListCount - 1
            If .Selected(i) = True Then
                ReDim Preserve arr(count)
                arr(count) = CStr(.List(i))
                count = count + 1
            End If
        Next i
    End With
[COLOR=#006400][I]'filter based on array[/I][/COLOR]
    With Sheets("Sheet3")
        .Range("A1").CurrentRegion.AutoFilter Field:=4, Criteria1:=arr, Operator:=xlFilterValues
        Unload Me
        .Activate
    End With
End Sub
 
Upvote 0
Is the listbox on a worksheet?
(tested with active-x listbox)

Place in sheet module of sheet containing the listbox
(right-click sheet tab \ View Code \ paste in code window \ {ALT}{F11} to go back to Excel)
Code:
Sub Filter_From_Sheet_Listbox_Selections()
    Dim i As Integer, count As Integer, arr() As Variant
[COLOR=#006400][I]'create array of selected items[/I][/COLOR]
    With [COLOR=#ff0000]ListBox1[/COLOR]
        count = 0
        For i = 0 To .ListCount - 1
            If .Selected(i) = True Then
                ReDim Preserve arr(count)
                arr(count) = CStr(.List(i))
                count = count + 1
            End If
        Next i
    End With
[COLOR=#006400][I]'filter based on array[/I][/COLOR]
    With Sheets("Sheet3")
        .Activate
        .Range("A1").CurrentRegion.AutoFilter Field:=4, Criteria1:=arr, Operator:=xlFilterValues
    End With
End Sub
 
Last edited:
Upvote 0
What did you work out?
How about posting your final solution to help future readers of the thread.
 
Upvote 0
My apologies - it's similar to the above:

Code:
Private Sub CommandButton1_Click()
ListBox1.MultiSelect = 1
    Worksheets("Headcount").Activate
    Dim APS_Lvl As Variant
    ReDim APS_Lvl(0)
    Application.ScreenUpdating = False
    For i = 0 To ListBox1.ListCount - 1
        If Me.ListBox1.Selected(i) Then
            APS_Lvl(UBound(APS_Lvl)) = Me.ListBox1.List(i)
            ReDim Preserve APS_Lvl(UBound(APS_Lvl) + 1)
        End If
    Next i
    Range("A2:O2000").AutoFilter Field:=5, Criteria1:=APS_Lvl, Operator:=xlFilterValues
    Application.ScreenUpdating = True
    Worksheets("Summary").Activate
    Unload Me
End Sub
 
Upvote 0

Forum statistics

Threads
1,215,328
Messages
6,124,295
Members
449,149
Latest member
mwdbActuary

We've detected that you are using an adblocker.

We have a great community of people providing Excel help here, but the hosting costs are enormous. You can help keep this site running by allowing ads on MrExcel.com.
Allow Ads at MrExcel

Which adblocker are you using?

Disable AdBlock

Follow these easy steps to disable AdBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the icon in the browser’s toolbar.
2)Click on the "Pause on this site" option.
Go back

Disable AdBlock Plus

Follow these easy steps to disable AdBlock Plus

1)Click on the icon in the browser’s toolbar.
2)Click on the toggle to disable it for "mrexcel.com".
Go back

Disable uBlock Origin

Follow these easy steps to disable uBlock Origin

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back

Disable uBlock

Follow these easy steps to disable uBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back
Back
Top