Option Explicit
Sub auto_open()
With Worksheets("sheet1")
.Protect Password:="hi", userinterfaceonly:=True
.EnableOutlining = True
'.EnableAutoFilter = True
'If .FilterMode Then
' .ShowAllData
'End If
End With
End Sub
It needs to be reset each time you open the workbook. (Earlier versions of
excel don't remember it after closing the workbook. IIRC, xl2002+ will remember
the allow autofilter setting under tools|Protection|protect sheet, but that
won't help when you're filtering via code.)
Ram B wrote:
>
> Does anyone know how to protect a worksheet and still have access to the
> "Group/Ungroup" functionality on the left ? Thanks!
--
Dave Peterson
Thanks
Ram
Then include them in .protect line
.Protect Password:="hi", userinterfaceonly:=True, _
AllowFormattingColumns:=True, AllowFormattingRows:=True
--
Dave Peterson
"Dave Peterson" wrote:
> Record a macro when you change the protection on the worksheet and change the
> settings you want.
>
> Then include them in .protect line
>
> ..Protect Password:="hi", userinterfaceonly:=True, _
If you wanted to avoid any sheets (based on a name):
> > > Option Explicit
> > > Sub auto_open()
dim wks as worksheet
for each wks in thisworkbook.worksheets
> > > With wks
select case lcase(.name)
case is = lcase("sheet1"),lcase("sheet99")
'do nothing, skip it
case else
> > > .Protect Password:="hi", userinterfaceonly:=True
> > > .EnableOutlining = True
> > > '.EnableAutoFilter = True
> > > 'If .FilterMode Then
> > > ' .ShowAllData
> > > 'End If
end select
> > > End With
next wks
> > > End Sub
--
Dave Peterson
Go back to your other post and see one reply.
If you remember where it is.
Best to post your own questions rather than piggy-backing on other people's
postings.
Gord Dibben MS Excel MVP