On many of his worksheets, Roy uses sorting and filtering extensively. On the Data tab of the ribbon, in the Sort & Filter group, there is a Clear tool. This tool clears all filtering and sorting settings. Roy routinely needs to clear the filtering settings, but he would like his sorting settings to remain unaffected by the clearing. He wonders if there is a way to either change how this tool behaves or to clear only the filtering settings in a single action.
This was an interesting problem to research, and it took a bit of poking and prodding. It appears that Excel allows you to define sorting settings for the filters you apply to a data set. To see this in action, follow these steps:
Note that the drop-down menu that appears allows you to select which data is filtered in the column. This is where people normally stop looking, though. It is interesting that at the top of the drop-down menu there are some sorting controls. If you use these controls, then the filtered results that Excel displays are filtered according to your specifications.
If you turn on the macro recorder at this point (after applying a filter that includes sorting) and click the Clear tool, this is the macro that is recorded by Excel:
Sub Macro1() ' ' Macro1 Macro ' ' ActiveWorkbook.Worksheets("Sheet1").AutoFilter.Sort.SortFields.Clear ActiveSheet.ShowAllData End Sub
Note that there are two lines in the recorded macro. The first line clears the sorting settings and the second clears all the filtering settings. If you record the same steps without having first chosen a sorting setting in the drop-down filtering menu at the top of a column, then Excel doesn't include the first line.
The upshot of this is that you can easily create your own single-line macro that removes any filtering but retains any sorting settings made through the filtering drop-down. The simple macro would look like this:
Sub ClearFilter() ActiveSheet.ShowAllData End Sub
It should be noted that if you turn off filtering (by clicking a second time on the Filter tool), Excel automatically clears any filtering and sorting settings you may have applied. If you want to retain sorting settings—particularly complex sorting settings—outside of the filtering framework, then it would be best to record a macro of the steps you go through for sorting your data.
Note:
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (12254) applies to Microsoft Excel 2007, 2010, 2013, and 2016.
Comprehensive VBA Guide Visual Basic for Applications (VBA) is the language used for writing macros in all Office programs. This complete guide shows both professionals and novices how to master VBA in order to customize the entire Office suite for their needs. Check out Mastering VBA for Office 2010 today!
When working with filtered data, you may want to specially format a column that has a filter applied to it. Here are a ...
Discover MoreWhen you print out a filtered worksheet, you may want some sort of printed record as to what filtering was applied to the ...
Discover MoreWhen you use Excel to input and store information, you need to be concerned with whether the information meets your ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
2018-07-01 20:43:09
William Howard Benson
Does not work if your activecell is not in the filtered range. In fact I have been questing for a means to unfilter, without removing autofilter, every table and any non-table filtered range on a worksheet. This one comes close, and does not require selecting in a table... but unfortunately as in your example above, it does *not* work for the rest of the filtered data on a worksheet without selecting at least one cell in the filtered region.
Sub UnfilterEverywhere()
Dim LO As ListObject
With ActiveSheet
For Each LO In .ListObjects
With LO
If Not LO.AutoFilter Is Nothing Then
LO.ShowAutoFilter = False
LO.ShowAutoFilter = True
End If
End With
Next
On Error Resume Next
.ShowAllData
On Error GoTo 0
End With
End Sub
2016-11-09 10:32:59
Scott L
Willy-
As my mother used to say "fer dumb!" You're right. Guess my muscle memory is better than my brain memory...
It's just a plain old "e", no "ctrl" necessary. At least in Excel 2010, 2013 and 2016. Win10 machines.
I discovered it by accident. It always annoyed me that there's an "alt+arrow+letter" shortcut to all the other options in the drop-down, but not to the edit box. One time I started typing before arrowing or mousing down and realized that an "e" I had typed had taken me there.
Yes, alt+arrow+c does clear the filter, but requires the top cell to be active. The macro keeps whichever cell is selected active without having to note the row or highlight it to find it again, which is something I often want.
2016-11-08 06:24:27
Willy Vanhaelen
@Scott L
Didn't know about Alt + Arrow. Very usefull.
But what do you mean with "Ctrl+e takes you to the edit box".
Ctrl+e just beeps on my system (Win 7, Excel 2007).
Playing around I found that with the top cell selected, Alt+arrow+c clears the Filter.
2016-11-07 14:35:48
Scott L
I use AutoFilter all the time. Here’s a couple of useful shortcuts:
With a top cell of any AutoFiltered range selected, Alt+Arrow(either up or down) opens the AutoFilter drop-down for that column.
With the drop-down open, Ctrl+e takes you to the edit box.
Also, I often want to remove the filter from a single column while leaving other filtered columns filtered.
I’ve assigned this macro to a shortcut key to reset the column filter for the active cell column without having to open the drop-down and click Select All:
Sub ResetColumn()
ActiveSheet.Cells.AutoFilter Field:=Selection.Column
End Sub
Got a version of Excel that uses the ribbon interface (Excel 2007 or later)? This site is for you! If you use an earlier version of Excel, visit our ExcelTips site focusing on the menu interface.
FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
Copyright © 2021 Sharon Parq Associates, Inc.
Comments