Autofilter using Named Ranges

ba99

New Member
Joined
Jul 25, 2007
Messages
4
This is the challenge I'm facing:

I want to create macro's which are intended to autofilter data in a sheet. However, if new columns get insterted or re-arranged in the sheet (it's a living file), all macro's need to be changed again since the columns get shifted and so does the FIELD:= value of the Autofilter command.

I want to keep the macro's flexible by making the Autofilter use the Range name, as you can define by INSERT > NAME > DEFINE, and not having the command using the FIELD:=1 for column A, etc...

Current Example (filter col B on YES)

Selection.AutoFilter Field:=2, Criteria1:="YES"

Desired Example (filter name defined Range on YES)

Selection.AutoFilter Field:=RANGENAME, Criteria1:="YES"

With the RANGENAME I want to use the name of a defined range, which is flexible.

Any help is really aprreciated!

Thanks,
BA
 

Excel Facts

Which lookup functions find a value equal or greater than the lookup value?
MATCH uses -1 to find larger value (lookup table must be sorted ZA). XLOOKUP uses 1 to find values greater and does not need to be sorted.

Anthony47

Well-known Member
Joined
Mar 29, 2006
Messages
3,244
Office Version
  1. 365
  2. 2010
Platform
  1. Windows
Hello BA, welcome.
I would suggest that you remove the existing autofilter, then apply it on the range, then you will always use Criteria1 for filtering.
For example this macro set the filter on range named frange:
Code:
Sub MaFilt()
On Error GoTo nofilt
Selection.AutoFilter Field:=1  'test autofilter
Selection.AutoFilter        'Remove autofilter
nofilt:
Range("frange").AutoFilter         'Assign autofilter
End Sub

Does it help? bye.
 

almagg

Well-known Member
Joined
Aug 21, 2002
Messages
705
i recorded some macros and did not come up with anything.
but how about this:

create an Input box so the user can type in the field of interest.
the macro then does a find on that field.
now, get the column number and assign it to a variable.
this variable can then be entered into the Field argument.

i just did a test:

myfield = 7
Selection.AutoFilter Field:=myfield, Criteria1:="$0"

and this worked.
 

Greg Truby

MrExcel MVP
Joined
Jun 19, 2002
Messages
10,022
BA,

Welcome to the board. Here's an example of what you're looking to do:
Code:
Sub foofilter()
    With Range("Fruits")
        .CurrentRegion.AutoFilter Field:=.Column - .CurrentRegion.Range("A1").Column + 1, _
                                  Criteria1:="Apple"
    End With
End Sub
 

ba99

New Member
Joined
Jul 25, 2007
Messages
4
Guys, thanks for the welcome and the help!

Greg; your post offered the best solution for me... great! I can move around, insert columns and rows, and it still will filter on the specific range.

Just curiosity (i'm learning): how does the part Range("A1").Column + 1 exactly work?

Anthony; your solution worked in the end as well, however in Almaggs I still had to work with integer references for the column.

Cheers,
BA[/code]
 

Forum statistics

Threads
1,181,657
Messages
5,931,265
Members
436,785
Latest member
KingGideon

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