Displaying Auto-Filter Conditions

  • Thread starter Thread starter Mark
  • Start date Start date
M

Mark

I'm using the AutoFilter feature to limit the range of
data shown in a spreadheet. Further, I wish to display the
filter condition (i.e., the value within the auto-filter
cell) in a summary page in order to make it clear which
sub-set of data are being shown. Any idea how this might
be done? Thank you.
 
Mark,

Tom Ogilvy has answered this one many times, so I will just copy his usual
reply:

'Start of quoted message

You could use a userdefined function to display it, such as this one:

Public Function ShowFilter(rng As Range)
Dim filt As Filter
Dim sCrit1 As String
Dim sCrit2 As String
Dim sop As String
Dim lngOp As Long
Dim lngOff As Long
Dim frng As Range
Dim sh As Worksheet
Set sh = rng.Parent
If sh.FilterMode = False Then
ShowFilter = "No Active Filter"
Exit Function
End If
Set frng = sh.AutoFilter.Range

If Intersect(rng.EntireColumn, frng) Is Nothing Then
ShowFilter = CVErr(xlErrRef)
Else
lngOff = rng.Column - frng.Columns(1).Column + 1
If Not sh.AutoFilter.Filters(lngOff).On Then
ShowFilter = "No Conditions"
Else
Set filt = sh.AutoFilter.Filters(lngOff)
On Error Resume Next
sCrit1 = filt.Criteria1
sCrit2 = filt.Criteria2
lngOp = filt.Operator
If lngOp = xlAnd Then
sop = " And "
ElseIf lngOp = xlOr Then
sop = " or "
Else
sop = ""
End If
ShowFilter = sCrit1 & sop & sCrit2
End If
End If
End Function


Since a filter change wouldn't necessarily cause it to recalc, you can enter
it like this:

=showfilter(B2)&CHAR(SUBTOTAL(9,B3)*0+32)

B2 is the header for one of the columns in the filter.

the function should be placed in a general module, not a sheet module.


'End of quote

HTH,
Bernie
MS Excel MVP
 
Bernie--
Thank you for your help! Works perfectly.

----- Bernie Deitrick wrote: -----

Mark,

Tom Ogilvy has answered this one many times, so I will just copy his usual
reply:

'Start of quoted message

You could use a userdefined function to display it, such as this one:

Public Function ShowFilter(rng As Range)
Dim filt As Filter
Dim sCrit1 As String
Dim sCrit2 As String
Dim sop As String
Dim lngOp As Long
Dim lngOff As Long
Dim frng As Range
Dim sh As Worksheet
Set sh = rng.Parent
If sh.FilterMode = False Then
ShowFilter = "No Active Filter"
Exit Function
End If
Set frng = sh.AutoFilter.Range

If Intersect(rng.EntireColumn, frng) Is Nothing Then
ShowFilter = CVErr(xlErrRef)
Else
lngOff = rng.Column - frng.Columns(1).Column + 1
If Not sh.AutoFilter.Filters(lngOff).On Then
ShowFilter = "No Conditions"
Else
Set filt = sh.AutoFilter.Filters(lngOff)
On Error Resume Next
sCrit1 = filt.Criteria1
sCrit2 = filt.Criteria2
lngOp = filt.Operator
If lngOp = xlAnd Then
sop = " And "
ElseIf lngOp = xlOr Then
sop = " or "
Else
sop = ""
End If
ShowFilter = sCrit1 & sop & sCrit2
End If
End If
End Function


Since a filter change wouldn't necessarily cause it to recalc, you can enter
it like this:

=showfilter(B2)&CHAR(SUBTOTAL(9,B3)*0+32)

B2 is the header for one of the columns in the filter.

the function should be placed in a general module, not a sheet module.


'End of quote

HTH,
Bernie
MS Excel MVP
 
Back
Top