Conditional protection of worksheets on save

Kelvin Stott

Active Member
Joined
Oct 26, 2010
Messages
338
Please help:

I need a macro that will automatically protect each sheet in a workbook when the workbook is saved, but only those sheets where the value of a certain cell has a specific value.

For example, when the workbook is saved, all sheets with cell B2 = "YES" should be protected, but not the others.

Any ideas how to do this please?
 

Excel Facts

Easy bullets in Excel
If you have a numeric keypad, press Alt+7 on numeric keypad to type a bullet in Excel.
In the ThisWorkbook module put

Code:
Private Sub Workbook_BeforeSave(ByVal SaveAsUI As Boolean, Cancel As Boolean)
Dim sh As Worksheet
    For Each sh In Sheets
        If sh.Range("B2") = "YES" Then sh.Protect "Password"
    Next sh
    
End Sub
 
Upvote 0
How would I edit this to protect all sheets, no conditions, no password?

(Excel 2000)

Thanks!
 
Upvote 0
Code:
Private Sub Workbook_BeforeSave(ByVal SaveAsUI As Boolean, Cancel As Boolean)
Dim sh As Worksheet 'replace worksheet with sheet, if you want to include chartsheets
    For Each sh In Sheets
        sh.Protect
    Next sh
    
End Sub
 
Last edited:
Upvote 0
Code:
Private Sub Workbook_BeforeSave(ByVal SaveAsUI As Boolean, Cancel As Boolean)
Dim sh As Worksheet 'replace worksheet with sheet, if you want to include chartsheets
    For Each sh In Sheets
        sh.Protect
    Next sh
 
End Sub


Perfect, perfect, perfect. Thank you, thank you, thank you!!
 
Upvote 0
I'm using microsoft office proffessional plus 2010.

I want to protect worksheets once a particular review date for that sheet has passed. I've tried modifying the code as follows:

Private Sub Workbook_BeforeSave(ByVal SaveAsUI As Boolean, Cancel As Boolean)
Dim sh As Worksheet
For Each sh In Sheets
If sh.Range("A1") < "TODAY()" Then sh.Protect "Password"
Next sh

End Sub

but it ends up with the whole workbook being protected when I hit save, regardless of what's in A1. What am I doing wrong?

(sorry complete code numpty here :))
 
Upvote 0
Try

Code:
Private Sub Workbook_BeforeSave(ByVal SaveAsUI As Boolean, Cancel As Boolean)
Dim sh As Worksheet
For Each sh In Sheets
    If sh.Range("A1").Value < Date Then sh.Protect "Password"
Next sh
End Sub
 
Upvote 0

Forum statistics

Threads
1,224,590
Messages
6,179,756
Members
452,940
Latest member
rootytrip

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