Protected sheets and grouping

icudoc

New Member
Joined
Oct 30, 2002
Messages
8
I can't seem to find a way to open and close grouped cells if any of the cells concerned are grouped. Is there any way to protect formulas in grouped cells, but still be able to open and close the grouping?
 

Excel Facts

Bring active cell back into view
Start at A1 and select to A9999 while writing a formula, you can't see A1 anymore. Press Ctrl+Backspace to bring active cell into view.

Andrew Poulsom

MrExcel MVP
Joined
Jul 21, 2002
Messages
73,092
Do you mean merged cells?

Cell protection applies to both contents and formatting. You will need to unprotect the worksheet to unmerge the cells.
 

icudoc

New Member
Joined
Oct 30, 2002
Messages
8
No, I mean grouped rows or columns.. a function on the data menu. Viewing or hiding the grouped rows/columns does not work if any of the cells in those rows/columns are protected, even though no changes are made to any of the individual cells when using the button to view/hide the grouped cells.
 

icudoc

New Member
Joined
Oct 30, 2002
Messages
8
Sorry readers, I have just read my initial post and I have used the word grouped twice instead of using the word protected. My problem is this, I cannot use the group function on any rows or columns that contain protected cells, even though grouping and hiding/viewing the grouped cells does not actually change individual cells formatting or contents.
 

Andrew Poulsom

MrExcel MVP
Joined
Jul 21, 2002
Messages
73,092

ADVERTISEMENT

Sorry, I misunderstood.

In VBA you can enable outlining on a protected sheet like this:

ActiveSheet.EnableOutlining = True
ActiveSheet.Protect contents:=True, userInterfaceOnly:=True

You cannot do this manually - you will have to unprotect the sheet.
 

icudoc

New Member
Joined
Oct 30, 2002
Messages
8
Thank you. I am not that familiar with VBA, how do I actually get that to run on a particular workbook (or sheet)
 

Andrew Poulsom

MrExcel MVP
Joined
Jul 21, 2002
Messages
73,092

ADVERTISEMENT

Right click the Excel icon to the left of File on the menu and choose View Code. Paste this code into the window on the right:

Code:
Private Sub Workbook_Open()
'   *** Change name of sheet to suit ***
    With Worksheets("Sheet1")
        .EnableOutlining = True
        .Protect contents:=True, userInterfaceOnly:=True
    End With
End Sub

Press Alt+F11 to return to your worksheet and close the workbook, saving changes. Reopen the workbook and outlining should be possible.
 

fredlo2008

Active Member
Joined
Jan 12, 2012
Messages
254
Hello,

Is there a way that I can do this for more than one sheet at the time. I have a huge workbook with about 30 sheets.

Thanks
 
Master Excel Bundle

Excel contains over 450 functions, with more added every year. That’s a huge number, so where should you start? Right here with this bundle.

Forum statistics

Threads
1,167,993
Messages
5,856,695
Members
431,828
Latest member
kARTIK12345

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