VBA to filter based on a cell value

cee_real

New Member
Joined
Mar 31, 2016
Messages
8
Hello,

I'm trying to filter two tables on a separate worksheet based on a value chosen from a drop down on my first worksheet.

Worksheet 1
-Drop Down Reference Cell G2

Worksheet 2
-Table 1 Range B21:Q116.
-Filter for column C21

Table 2 Range B122:Q216
-Filter for column C122

Any help is appreciated.
 

Excel Facts

Who is Mr Spreadsheet?
Author John Walkenbach was Mr Spreadsheet until his retirement in June 2019.
See if this does what you want. Test in a copy of your workbook.

To implement ..
1. Right click name tab of Sheet1 and choose "View Code".
2. Copy and Paste the code below into the main right hand pane that opens at step 1. (Check the sheet name in the code is the same as your sheet with the tables. The table names should also be checked.)
3. Close the Visual Basic window & test.
4. Your workbook will need to be saved as a macro-enabled workbook (*.xlsm).

Rich (BB code):
Private Sub Worksheet_Change(ByVal Target As Range)
  Dim sCrit As String
  
  If Not Intersect(Target, Range("G2")) Is Nothing Then
    With Sheets("Sheet2")
      .ListObjects("Table1").Range.AutoFilter Field:=2
      .ListObjects("Table2").Range.AutoFilter Field:=2
      sCrit = Range("G2").Value
      If Len(sCrit) > 0 Then
        .ListObjects("Table1").Range.AutoFilter Field:=2, Criteria1:=sCrit
        .ListObjects("Table2").Range.AutoFilter Field:=2, Criteria1:=sCrit
      End If
    End With
  End If
End Sub
 
Upvote 0

Forum statistics

Threads
1,214,561
Messages
6,120,225
Members
448,951
Latest member
jennlynn

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