reset filter when double click same cell twice

hajiali

Well-known Member
Joined
Sep 8, 2018
Messages
623
Office Version
  1. 2016
Platform
  1. Windows
VBA Code:
Private Sub Worksheet_BeforeDoubleClick(ByVal Target As Range, Cancel As Boolean)
    Dim rngCol As Range
    Dim Nextnum As Long
  
    Set rngCol = Me.Columns("A:A")
    If Not Intersect(rngCol, Target) Is Nothing Then
        Cancel = True
        Select Case Target.Value
        Case Is <> "": Target.ClearContents
        Case Else
        Nextnum = WorksheetFunction.Max(rngCol) + 1
        Target.Value = Nextnum
        End Select
    End If
    If Not Intersect(Target, Range("C2")) Is Nothing Then
    Cancel = True
      ActiveSheet.Unprotect Password:="password"
      ActiveSheet.Range("$A$3:$Q$603").AutoFilter Field:=3, Criteria1:="OFF"
      ActiveSheet.Protect Password:="password", AllowFiltering:=True
End If
End Sub

using the above code im able to double click C2 and it Filters the Field with "OFF." I want to add the function to reset ("Select All") in the column filter when double click again.

Thanks
 
Hey Fluff how with the above code how would I adjust it to make it When I double click the second time instead of selects all to selects All except blanks "<>"?
 
Upvote 0

Excel Facts

Spell Check in Excel
Press F7 to start spell check in Excel. Be careful, by default, Excel does not check Capitalized Werds (whoops)
How about
VBA Code:
           If .AutoFilter.Filters.Item(Target.Column).On Then
               .Range("A3:Q3").AutoFilter Target.Column,"<>"
            Else
 
Upvote 0
This is where I assume the change goes with this the Select all except Blank works, however , the Filter "OFF" does not when I double Click again

VBA Code:
If Not Intersect(Target, Range("C2")) Is Nothing Then
      Cancel = True
      Me.Unprotect Password:="PASSWORD"
      With ActiveSheet
         If .AutoFilterMode Then
            If .AutoFilter.Filters.item(Target.Column).On Then
               .Range("A3:Q3").AutoFilter Target.Column, "<>"
               Else
               .Range("$A$3:$Q$501", "$A$503:$Q$603").AutoFilter field:=Target.Column, Criteria1:="OFF"
            End If
         Else
             .Range("$A$3:$Q$501", "$A$503:$Q$603").AutoFilter field:=Target.Column, Criteria1:="OFF"
        End If
      End With
      Me.Protect Password:="PASSWORD", AllowFiltering:=True
   End If
 
Upvote 0
Hey Fluff not sure if you have a chance to look at my Post #13
 
Upvote 0
Apologies, must have missed this.
How about
VBA Code:
Private Sub Worksheet_BeforeDoubleClick(ByVal Target As Range, Cancel As Boolean)
   If Not Intersect(Target, Range("C2")) Is Nothing Then
      Cancel = True
      With Me
         .Unprotect Password:="PASSWORD"
         If .AutoFilterMode Then
            If .AutoFilter.Filters.Item(Target.Column).On Then
               If .AutoFilter.Filters.Item(Target.Column).Criteria1 = "=OFF" Then
                  .Range("A3:Q3").AutoFilter Target.Column, "<>"
                  .Protect Password:="PASSWORD", AllowFiltering:=True
                  Exit Sub
               End If
            End If
         End If
         .Range("A3:Q3").AutoFilter Field:=Target.Column, Criteria1:="OFF"
         .Protect Password:="PASSWORD", AllowFiltering:=True
      End With
   End If
End Sub
 
Upvote 0

Forum statistics

Threads
1,213,534
Messages
6,114,186
Members
448,554
Latest member
Gleisner2

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