Filter

davidhall80

Well-known Member
Joined
Jul 8, 2006
Messages
663
I have a filter on column B Whatever name I choose for column B, I want cell G1 to equal that as well, is this possible. As i make changes to my filter, I would like G1 to update as well. possible?
 

Excel Facts

Which came first: VisiCalc or Lotus 1-2-3?
Dan Bricklin and Bob Frankston debuted VisiCalc in 1979 as a Visible Calculator. Lotus 1-2-3 debuted in the early 1980's, from Mitch Kapor.

dave3009

Well-known Member
Joined
Jun 23, 2006
Messages
7,079
Office Version
  1. 365
  2. 2021
Platform
  1. Windows
  2. Mobile
  3. Web
Hi This isn't exactly what you're looking for but it might help to some point.

In Sheet1 I have made a ComboBox over B1, I have linked it to G1 and filled it with a range from another group of cells in the workbook.

I then use the following code to filter from it

Code:
Private Sub ComboBox1_Change()
Dim i As Integer
 i = Sheets("Sheet1").Range("G1").Value
    Selection.AutoFilter Field:=2, Criteria1:=i
    
End Sub

You might need to alter it to suit your needs

HTH


Dave
 

Peter_SSs

MrExcel MVP, Moderator
Joined
May 28, 2005
Messages
55,785
Office Version
  1. 365
Platform
  1. Windows
davidhall80

You could try this:
1. In H1: =NOW()
This forces the sheet to recalculate when the Filter is changed and therefore triggers the code in step 3 below.
2. In I1: =COUNTA(B:B)-SUBTOTAL(3,B:B)
3. The following WorkSheet_Calculate code

<font face=Courier New><SPAN style="color:#00007F">Private</SPAN> <SPAN style="color:#00007F">Sub</SPAN> Worksheet_Calculate()
    <SPAN style="color:#00007F">Dim</SPAN> Row <SPAN style="color:#00007F">As</SPAN> <SPAN style="color:#00007F">Long</SPAN>
    Application.EnableEvents = <SPAN style="color:#00007F">False</SPAN>
    Application.ScreenUpdating = <SPAN style="color:#00007F">False</SPAN>
    <SPAN style="color:#00007F">If</SPAN> Range("I1").Value <> 0 <SPAN style="color:#00007F">Then</SPAN>
        Row = 2
        <SPAN style="color:#00007F">Do</SPAN> <SPAN style="color:#00007F">While</SPAN> Cells(Row, 2).EntireRow.Hidden = <SPAN style="color:#00007F">True</SPAN>
         Row = Row + 1
        <SPAN style="color:#00007F">Loop</SPAN>
        Range("G1").Value = Cells(Row, 2).Value
    <SPAN style="color:#00007F">Else</SPAN>
        Range("G1").Value = "N/A"
    <SPAN style="color:#00007F">End</SPAN> <SPAN style="color:#00007F">If</SPAN>
    Application.EnableEvents = <SPAN style="color:#00007F">True</SPAN>
    Application.ScreenUpdating = <SPAN style="color:#00007F">True</SPAN>
<SPAN style="color:#00007F">End</SPAN> <SPAN style="color:#00007F">Sub</SPAN></FONT>

The formulas in H1 and I1 could be moved elsewhere on the sheet and possibly hidden. If the I1 formula is moved to another cell, then the reference to it in the above code would also need to be changed.
 

Forum statistics

Threads
1,171,579
Messages
5,876,290
Members
433,192
Latest member
butterexcel

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