Formatting columns in a protected sheet

afrattar

New Member
Joined
May 9, 2022
Messages
2
Office Version
  1. 2021
Platform
  1. Windows
Hello,

I have a spreadsheet that I would like to protect but allow for column formatting. I have a macro in the sheet to allow for more than one dropdown choice. This unprotects and protects and I think may be the problem. I have tried adding the following with no success. As soon as I add data to a cell the ability to format the column is not available.

Sub ProtectButAllowFormatting()

ActiveSheet.Protect _
Password:=(123), _
AllowFormattingColumns:=True, _
AllowFormattingRows:=True

End Sub


Here is the vba for the dropdown. Can you help me with adding the formatting for columns to work in a protected sheet with this also running?

Private Sub Worksheet_Change(ByVal Target As Range)
' Code by Sumit Bansal from TrumpExcel
' To allow multiple selections in a Drop Down List in Excel (without repetition)
Dim Oldvalue As String
Dim Newvalue As String
Me.Unprotect Password:="123"
On Error GoTo ExitSub
If (Target.Column = 18 Or Target.Column = 22) Then
If Target.SpecialCells(xlCellTypeAllValidation) Is Nothing Then
GoTo ExitSub
ElseIf Target.Value = "" Then
GoTo ExitSub
Else
Application.EnableEvents = False
Newvalue = Target.Value
Application.Undo
Oldvalue = Target.Value
If Oldvalue = "" Then
Target.Value = Newvalue
ElseIf InStr(1, Oldvalue, Newvalue) = 0 Then
Target.Value = Oldvalue & ", " & Newvalue
Else
Target.Value = Oldvalue
End If
End If
End If
ExitSub:
Application.EnableEvents = True
Me.Protect Password:="123"
End Sub
 

Excel Facts

Return population for a City
If you have a list of cities in A2:A100, use Data, Geography. Then =A2.Population and copy down.
For anyone who wants to know.
I changes the 'Me.Protect Password:="123" just before End Sub
to
Me.Protect Password:="123", AllowFormattingColumns:=True, AllowFormattingRows:=True
 
Upvote 0

Forum statistics

Threads
1,213,486
Messages
6,113,932
Members
448,533
Latest member
thietbibeboiwasaco

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