Option Explicit
Option Base 1
'''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''
Sub Protect_All()
'
' Macro to apply a (single) password to all sheets in a workbook and to the workbook itself.
'
Dim WorkSht As Worksheet, ThisChart As Chart, NumbSheets As Long, NumbCharts As Long
Dim PassWd, RePassWd, Ans, ShtName As String, ShtType As String, I As Integer
Const Descr As String = "Macro to fully protect a workbook"
'
' Warn user what is about to happen.
'
Ans = MsgBox("You are about to protect all sheets & charts in this workbook." & _
Chr(13) & Chr(13) & "Do you wish to continue?", _
vbYesNoCancel + vbDefaultButton1, Descr)
If Ans = vbCancel Or Ans = vbNo Then
MsgBox "Operation cancelled at your request.", vbOKOnly, Descr
Exit Sub
End If
'
' Get from the user the password to be used and Verify the the password with a second entry
' of the password. If they do not match repeat the entry process (up to 3 times).
'
' Note that the "Application." in front of the "InputBox" for the latter is necessary
' to be able to distinguish between a blank password and a "cancel" response, since with it
' a cancel will return a boolean "false", while without it a cancel will return an empty
' string.
'
For I = 1 To 3
PassWd = Application.InputBox("Please enter the password you want to use:", Descr)
If VarType(PassWd) = vbBoolean Then
If Not PassWd Then
MsgBox "Operation cancelled at your request.", vbOKOnly, Descr
Exit Sub
End If
End If
'
RePassWd = Application.InputBox("Please re-enter the password:", Descr)
If VarType(RePassWd) = vbBoolean Then
If Not RePassWd Then
MsgBox "Operation cancelled at your request.", vbOKOnly, Descr
Exit Sub
End If
End If
'
If PassWd = RePassWd Then
Exit For
Else
If I < 3 Then
MsgBox "Your passwords do not match. Try again.", , Descr
GoTo Try_Again
Else
MsgBox "Another mis-match. Three strikes and you're out.", vbOKOnly, Descr
Exit Sub
End If
End If
Try_Again:
Next I
'
' Check to see if any of the worksheets or chartsheets are currently protected.
' If we find a protected sheet we abort the entire process.
'
For Each WorkSht In Worksheets
If WorkSht.ProtectContents Then
MsgBox "You appear to have some sheets that are already protected. " & Chr(13) & _
"Please un-protect all sheets/charts before running this macro."
Exit Sub
End If
Next WorkSht
'
For Each ThisChart In Charts
If ThisChart.ProtectContents Then
MsgBox "You appear to have some charts that are already protected. " & Chr(13) & _
"Please un-protect all sheets/charts before running this macro."
Exit Sub
End If
Next ThisChart
'
' Checks all passed. Can now get on with the main job.
'
' Loop through all the worksheets.
'
NumbSheets = 0
ShtType = "Worksheet "
For Each WorkSht In Worksheets
ShtName = WorkSht.Name
On Error GoTo P_Failure
'
WorkSht.Protect DrawingObjects:=True, Contents:=True, Scenarios:=True, AllowSorting:=True, AllowFiltering:=True, Password:=PassWd
'
' Allow user to select (but not change) locked cells. Note that with some versions
' of Excel this setting does not persist (ie it gets forgotten when the workbook
' is saved.
'
WorkSht.EnableSelection = xlNoRestrictions
'
On Error GoTo 0
NumbSheets = NumbSheets + 1
Next WorkSht
'
' Loop through all the charts.
'
NumbCharts = 0
ShtType = "Chart "
For Each ThisChart In Charts
ShtName = ThisChart.Name
On Error GoTo P_Failure
ThisChart.Protect DrawingObjects:=True, Contents:=True, Scenarios:=True, Password:=PassWd
On Error GoTo 0
NumbCharts = NumbCharts + 1
Next ThisChart
'
' Now protect the workbook itself.
'
ShtType = ""
ShtName = "Workbook's structure"
On Error GoTo P_Failure
ActiveWorkbook.Protect Structure:=True, Windows:=False, Password:=PassWd
On Error GoTo 0
'
' It's all over.
'
MsgBox "All done OK (" & NumbSheets & " sheets and " & NumbCharts & " charts)." & Chr(13) & Chr(13) & _
"Password used was """ & PassWd & """." & Chr(13) & Chr(13) & _
"Take care not to forget it.", vbOKOnly, Descr
Exit Sub
'
' Error handling area.
'
P_Failure:
MsgBox "Protection attempt failed for " & ShtType & ShtName & " so exercise was aborted." & _
Chr(13) & Chr(13) & _
Err & ": " & Error(Err), _
vbOKOnly, Descr
End Sub
'''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''
Sub Unprotect_All()
'
' Macro to unprotect all sheets in a workbook, and the workbook itself.
' It assumes that all these protections have been set with the same password.
'
Dim WorkSht As Worksheet, ThisChart As Chart, NumbSheets As Long, NumbCharts As Long
Dim Ans, PassWd, ShtName As String, ShtType As String
Const Descr As String = "Macro to fully unprotect a workbook"
'
' Warn user what is about to happen.
'
Ans = MsgBox("You are about to unprotect all sheets & charts in this workbook." & _
Chr(13) & Chr(13) & "Do you wish to continue?", _
vbYesNoCancel + vbDefaultButton1, Descr)
If Ans = vbCancel Or Ans = vbNo Then
MsgBox "Operation cancelled at your request.", vbOKOnly, Descr
Exit Sub
End If
'
' Get the password from the user.
' (See above for comments on the "Application." bit.)
'
PassWd = Application.InputBox("Please enter the password:", Descr)
If VarType(PassWd) = vbBoolean Then
If Not PassWd Then
MsgBox "Operation cancelled at your request.", vbOKOnly, Descr
Exit Sub
End If
End If
'
' Loop through all the worksheets.
'
NumbSheets = 0
ShtType = "Worksheet "
For Each WorkSht In Worksheets
ShtName = WorkSht.Name
On Error GoTo U_Failure
WorkSht.Unprotect Password:=PassWd
On Error GoTo 0
NumbSheets = NumbSheets + 1
Next WorkSht
'
' Loop through all the charts.
'
NumbCharts = 0
ShtType = "Chart "
For Each ThisChart In Charts
ShtName = ThisChart.Name
On Error GoTo U_Failure
ThisChart.Unprotect Password:=PassWd
On Error GoTo 0
NumbCharts = NumbCharts + 1
Next ThisChart
'
' Now unprotect the workbook itself.
'
ShtType = ""
ShtName = "Workbook's structure"
On Error GoTo U_Failure
ActiveWorkbook.Unprotect Password:=PassWd
On Error GoTo 0
'
' It's all over.
'
MsgBox "All done OK (" & NumbSheets & " sheets and " & NumbCharts & " charts).", vbOKOnly, Descr
Exit Sub
'
' Error handling area.
'
U_Failure:
MsgBox "Unprotection attempt failed for " & ShtType & ShtName & " so exercise was aborted." & _
Chr(13) & Chr(13) & _
Err & ": " & Error(Err), _
vbOKOnly, Descr
End Sub