Macro Coding Help

andyreloaded

Board Regular
Joined
Aug 1, 2006
Messages
80
I have a spreadsheet with 50 or so tabs that I want to protect and unprotect with a macro. So when I run the LOCK macro, it prompts once for a password, then cycles through all the sheets locking them with that password. And when I run the UNLOCK macro, it prompts once for my password, then cycles through all the sheets unlocking them with that password.

Here is what I have so far, but it has the password actually coded into the macro instead of prompting. Thanks for all your help, as always!

LOCK

Sub LockFormulas()
Dim WkSht As Integer
For WkSht = 1 To Worksheets.Count
With Sheets(WkSht)
On Error Resume Next
.Cells.Locked = False
.Cells.SpecialCells(xlCellTypeFormulas, 23).Locked = True
.Protect "mypassword"
Err.Clear
End With
Next WkSht
End Sub

UNLOCK

Sub UnlockFormulas()
Dim WkSht As Integer
For WkSht = 1 To Worksheets.Count
With Sheets(WkSht)
.Unprotect "mypassword"
End With
Next WkSht
End Sub
 

Excel Facts

Test for Multiple Conditions in IF?
Use AND(test, test, test, test) or OR(test, test, test, ...) as the logical_test argument of IF.
You can use an inputbox to get the value from the user and save it as a variable:

Code:
Sub LockFormulas()
Dim WkSht As Worksheet, strPass As String

strPass = InputBox("Enter the password to continue.")
If strPass = "" Then Exit Sub

For Each WkSht In ThisWorkbook.Worksheets
    With WkSht
        On Error Resume Next
        .Cells.Locked = False
        .Cells.SpecialCells(xlCellTypeFormulas, 23).Locked = True
        .Protect strPass
        Err.Clear
    End With
Next WkSht

End Sub



Sub UnlockFormulas()
Dim WkSht As Worksheet, strPass As String

strPass = InputBox("Enter the password to continue.")
If strPass = "" Then Exit Sub

For Each WkSht In ThisWorkbook.Worksheets
    WkSht.Unprotect strPass
Next WkSht

End Sub

Note that the code I posted above does not include error trapping. If you enter an incorrect password, an error will occur.
 
Upvote 0

Forum statistics

Threads
1,214,919
Messages
6,122,259
Members
449,075
Latest member
staticfluids

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