VBA Run-time error 1004 when auto-filtering

stevieinselby

New Member
Joined
Nov 12, 2015
Messages
27
I have a shared workbook with frozen frames and autofilters. You know what's coming next ... yes, other people frequently leave filters set, and that messes things up when the next person comes along, takes the filters off, and now the first umpteen rows are frozen and they can't scroll. So I have put code into Workbook_Open that unfilters the page and resets the frozen frames ... all working fine. I also want to set one particular filter, and after about 100 attempts I have managed to get that working ... but only when the workbook is not shared. As soon as I share the workbook, I get the dreaded Run-time error '1004': Application-defined or object-defined error. And now because the workbook is shared, I can't even debug it to find where the error is. The worksheet is protected, I don't know if that makes a difference.

Code:
With Sheets("Sheet1")
.Activate
ActiveSheet.AutoFilter.ShowAllData
ActiveWindow.FreezePanes = False
ActiveWindow.SplitColumn = 3
ActiveWindow.SplitRow = 1
ActiveWindow.FreezePanes = True
.Range("C1:BC1").AutoFilter
.Range("C1:BC1").AutoFilter Field:=8, Criteria1:="M"
End With

If I put On Error Resume Next then it does everything in Workbook_Open except applying the filter Field8="M"

Any suggestions as to how to make it work? Or am I trying to achieve something that Excel makes impossible?
 

Excel Facts

Pivot Table Drill Down
Double-click any number in a pivot table to create a new report showing all detail rows that make up that number
Hi,

It is more than likely the fact the worksheet is protected. you can unprotect and reprotect using the macro if you know the password using worksheet.unprotect (password) at the start of the macro.

and worksheet.protect(password) at the end.
 
Upvote 0
Actually it looks though you also have an unnecessary step in there and instead of showing all, i just changed to disable the filter.

See below (edited to make last row dynamic)

Code:
Sub filtersheets()
Dim LR As Long
LR = ActiveSheet.Range("A" & Rows.Count).End(xlUp).Row
With Sheets("Sheet1")
.Activate
.AutoFilterMode = False
ActiveWindow.FreezePanes = False
ActiveWindow.SplitColumn = 3
ActiveWindow.SplitRow = 1
ActiveWindow.FreezePanes = True
.Range("C1:BC" & LR).AutoFilter , Field:=8, Criteria1:="M"
End With
End Sub
 
Last edited:
Upvote 0
How about
Code:
With Sheets("Sheet2")
   .Activate
If .AutoFilterMode And .FilterMode Then .ShowAllData
   ActiveWindow.FreezePanes = False
   ActiveWindow.SplitColumn = 3
   ActiveWindow.SplitRow = 1
   ActiveWindow.FreezePanes = True
   .Range("C1:BC1").AutoFilter Field:=8, Criteria1:="M"
End With
End Sub
 
Upvote 0
That works a treat when the workbook isn't shared, but as soon as it is shared, it falls over. If I follow that line and replace ActiveSheet.AutoFilter.ShowAllData with .AutoFilterMode=False in a shared workbook then when the whirring and clanking has finished, it doesn't have AutoFilter on at all. It appears that, in a shared and protected sheet, VB can remove the AutoFilter without any trouble but can't put it back in. :sigh: :headbang:

But useful to know that there's a better syntax than the one I was using, even if it doesn't solve this particular problem!
 
Upvote 0
What error message did you get with my code?
 
Upvote 0

Forum statistics

Threads
1,223,893
Messages
6,175,240
Members
452,621
Latest member
Laura_PinksBTHFT

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