Clear filters from ALL sheets, on workbook close

Rob_010101

Board Regular
Joined
Jul 24, 2017
Messages
198
Office Version
  1. 365
Platform
  1. Windows
Hi

I need a VBA code to clear/reset all filters from all sheets upon workbook close.

A number of users of a workbook are always leaving filtered criteria applied and exiting. With some sheets having 100 columns, it sometimes causes problems when others open the workbook and think data is missing. There are about 40 people who use this workbook and some are not advanced excel users.

The code should not get rid of the filters, just clear the filtered criteria when the workbook is closed so that it's reset back to showing all data when anyone opens it.

KR
Chris
 

Excel Facts

How to find 2nd largest value in a column?
MAX finds the largest value. =LARGE(A:A,2) will find the second largest. =SMALL(A:A,3) will find the third smallest
Hi
Try this in Thisworkbook code
VBA Code:
Private Sub Workbook_BeforeClose(Cancel As Boolean)
Dim i&
For i = 1 To Sheets.Count
 With Sheets(i)
        If .FilterMode = True Then .ShowAllData
    End With
Next
End Sub
 
Upvote 1
The above code will crash if you have a Chart sheet - use Worksheets instead of Sheets. Also, save the workbook to preserve the changes
VBA Code:
Private Sub Workbook_BeforeClose(Cancel As Boolean)
    Dim ws As Worksheet
    For Each ws In ThisWorkbook.Worksheets
        If ws.AutoFilterMode Then ws.AutoFilter.ShowAllData
    Next
    ThisWorkbook.Save
End Sub
 
Upvote 2
Solution

Forum statistics

Threads
1,223,227
Messages
6,170,853
Members
452,361
Latest member
d3ad3y3

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