VBA to adjust column filter, based on dropdown selection?

DarkJester89

Board Regular
Joined
Nov 5, 2017
Messages
84
Office Version
  1. 2016
Platform
  1. Windows
Sheet 1, data with filters

Sheet 2, Dropdown with name range of filter data

Respectfully requesting how to activate filter based on dropdown, to include "All Regions", which would reset the filter to count all.

tests.png


Workbook

Had assistance with this code with a warning of " code for updating the range of the filter itself " but it keeps throwing up 1004.

VBA Code:
Option Explicit

Private Sub Worksheet_Change(ByVal Target As Range)
    If Not Intersect(Target, Range("M2")) Is Nothing Then
        Select Case Target.Value
            Case "All Regions"
                ActiveSheet.Range("$G$1:$G$134").AutoFilter Field:=1
            Case Else
                ActiveSheet.Range("$G$1:$G$134").AutoFilter Field:=1, Criteria1:=Target.Value
        End Select
    End If
End Sub

Thank you in advance.
 

Some videos you may like

Excel Facts

Create a Pivot Table on a Map
If your data has zip codes, postal codes, or city names, select the data and use Insert, 3D Map. (Found to right of chart icons).

Fluff

MrExcel MVP, Moderator
Joined
Jun 12, 2014
Messages
48,165
Office Version
  1. 365
Platform
  1. Windows
Is col G part of a table?
If so what is it's name?
 

Fluff

MrExcel MVP, Moderator
Joined
Jun 12, 2014
Messages
48,165
Office Version
  1. 365
Platform
  1. Windows
How about
VBA Code:
Private Sub Worksheet_Change(ByVal Target As Range)
   If Not Intersect(Target, Range("M2")) Is Nothing Then
      With ActiveSheet.ListObjects("table_owssvr")
         Select Case Target.Value
            Case "All Regions"
               If .AutoFilter.FilterMode Then .AutoFilter.ShowAllData
            Case Else
            .Range.AutoFilter .ListColumns("Region").Index, Target.Value
         End Select
      End With
   End If
End Sub
 

DarkJester89

Board Regular
Joined
Nov 5, 2017
Messages
84
Office Version
  1. 2016
Platform
  1. Windows
It works! If I was trying to adjust Range "M1" (moving the dropdown to another sheet), how could I could the new location if it's on another sheet?

Would a change like that force ListColumns to need an update as well? thank you so much!
 

Fluff

MrExcel MVP, Moderator
Joined
Jun 12, 2014
Messages
48,165
Office Version
  1. 365
Platform
  1. Windows
You would need to put the code in the sheet with the dropdown & replace ActiveSheet with the name of the sheet with the table.
 

Watch MrExcel Video

Forum statistics

Threads
1,114,098
Messages
5,545,952
Members
410,713
Latest member
TaremyLunsil
Top