VBA to clear all filters on table on each Worksheet in Workbook

dellzy

Board Regular
Joined
Apr 24, 2013
Messages
146
Dear Excel Experts,

I found many sets of macros to clear all filters in a workbook. I've tried 4 of them but all doesn't seem to work. The filter still exists altho no error when running the macro. Below is one of the codes I tried.
Is there anything I did wrong? Please help because I need to do this for 80 worksheets in each workbook with total 95 workbooks.

Code:
Sub AutoFiltersOff()

  Dim Wks As Worksheet
    
    For Each Wks In Worksheets
      If Wks.AutoFilterMode = True Then
         Wks.UsedRange.AutoFilter
      End If
    Next Wks


End Sub

Thank you in advance.

DZ
 

Some videos you may like

Excel Facts

Did you know Excel offers Filter by Selection?
Add the AutoFilter icon to the Quick Access Toolbar. Select a cell containing Apple, click AutoFilter, and you will get all rows with Apple

vcoolio

Well-known Member
Joined
Jun 29, 2014
Messages
1,054
Hello Dellzy,

As far as I can tell, you may want to change this line:_

Code:
  Wks.UsedRange.AutoFilter

to

Code:
 wks.AutoFilterMode = False

.......or, to not use the "IF" statement, try:-

Code:
For Each wKs In ThisWorkbook.Worksheets
        wKs.AutoFilterMode = False
    Next wKs

Cheerio,
vcoolio.
 

dellzy

Board Regular
Joined
Apr 24, 2013
Messages
146
Hi,

All of the suggestions above I've tried earlier before posting this questions. All not seem to work.. That's why I feel weird. :(

Hello Dellzy,

As far as I can tell, you may want to change this line:_

Code:
  Wks.UsedRange.AutoFilter

to

Code:
 wks.AutoFilterMode = False

.......or, to not use the "IF" statement, try:-

Code:
For Each wKs In ThisWorkbook.Worksheets
        wKs.AutoFilterMode = False
    Next wKs

Cheerio,
vcoolio.
 

vcoolio

Well-known Member
Joined
Jun 29, 2014
Messages
1,054
Hello Dellzy,

I can't see why it wouldn't work. I've just tested both and all is fine. However, I did notice above that I have a mix of upper and lower case with wKs. Sorry!
This should be exactly as you've declared your variable in all parts of the code (Wks). Try adjusting this to see if it sorts it out for you.

Cheerio,
vcoolio.

P.S. Leave out the "UsedRange" part regardless.
 
Last edited:

Akuini

Well-known Member
Joined
Feb 1, 2016
Messages
2,959
Office Version
  1. 365
Platform
  1. Windows
All of the suggestions above I've tried earlier before posting this questions. All not seem to work.. That's why I feel weird.
Is your data in a table (not just a range)? Because the codes above won't affect tables.
 

Akuini

Well-known Member
Joined
Feb 1, 2016
Messages
2,959
Office Version
  1. 365
Platform
  1. Windows
For data in table, try this:
Code:
Sub unFilters2()
    Dim ws As Worksheet
    Dim tObj As ListObject

    For Each ws In ActiveWorkbook.Worksheets
        For Each tObj In ws.ListObjects
                tObj.AutoFilter.ShowAllData
        Next
    Next ws
End Sub
 

Watch MrExcel Video

Forum statistics

Threads
1,127,105
Messages
5,622,764
Members
415,926
Latest member
jerrynababa

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
Top