Removing Select from code

schielrn

Well-known Member
Joined
Apr 4, 2007
Messages
6,941
Below is my code that changes my "cover" sheet based on a filter in the "detail" sheet. My "cover" sheet uses subtotals and has a combo box on there to select different regions. I would like to get rid of the .selects, but I can't figure out how to use With sheets("detail") to get rid of them.

Any help would be appreciated. Thanks.

Code:
Sub DropDown2_Change()
Application.ScreenUpdating = False
If (Range("C15").Value = 2) Then
Sheets("detail").Select
Selection.AutoFilter Field:=1, Criteria1:="North Central"
Sheets("cover").Select
ElseIf (Range("C15").Value = 1) Then
Sheets("detail").Select
Selection.AutoFilter Field:=1, Criteria1:="West"
Sheets("cover").Select
ElseIf (Range("C15").Value = 3) Then
Sheets("detail").Select
Selection.AutoFilter Field:=1, Criteria1:="South Central"
Sheets("cover").Select
ElseIf (Range("C15").Value = 4) Then
Sheets("detail").Select
Selection.AutoFilter Field:=1, Criteria1:="HDQ"
Sheets("cover").Select
ElseIf (Range("C15").Value = 5) Then
Sheets("detail").Select
Selection.AutoFilter Field:=1
Sheets("cover").Select
End If
Application.ScreenUpdating = True
End Sub
 
Norie, the way I did it, it did need the range for it to work. I had autofilter already turned on, but it was giving me that error until I specified the range. Yours worked except for when I didn't want it to filter at all and just return it to all data.

Code:
Sub DropDown2_Change()
Application.ScreenUpdating = False
Select Case Sheets("cover").Range("C15").Value
Case 2
    Sheets("detail").Range("A4:H4").AutoFilter Field:=1, Criteria1:="North Central"
Case 1
    Sheets("detail").Range("A4:H4").AutoFilter Field:=1, Criteria1:="West"
Case 3
    Sheets("detail").Range("A4:H4").AutoFilter Field:=1, Criteria1:="South Central"
Case 4
    Sheets("detail").Range("A4:H4").AutoFilter Field:=1, Criteria1:="HDQ"
Case 5
    Sheets("detail").Range("A4:H4").AutoFilter Field:=1
End Select
Application.ScreenUpdating = True
End Sub
 
Upvote 0

Excel Facts

Can a formula spear through sheets?
Use =SUM(January:December!E7) to sum E7 on all of the sheets from January through December
schielrn

You should always try and reference everything. eg Ranges, Worksheets etc

If you don't you might find you get some strange results and/or errors.

In jonmo's code he references the worksheet then referring to C15, this ensures VBA is 'looking' at C15 on the correct sheet.

Without that worksheet reference VBA would be 'looking' at C15 on the active sheet.

As to my code, like I said not tested, and I wasn't actually sur what that last filter was for.:)

It could be rewritten to deal with that case but if what you have works use it.:)
 
Upvote 0
Thank you. I'm learning more and more everyday. I was not too familiar with Case Select and now I know a little more. I really likeed your solution since it was more concise.
 
Upvote 0
The last one should be OK, as not specifying a criteria sets it to show all.
 
Upvote 0

Forum statistics

Threads
1,213,536
Messages
6,114,215
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