Got any Excel/VBA Questions? Free Excel Help
Excel macros are a great way to save time and eliminate errors. However, sooner or later you may try to run your favorite Excel Macro on a Worksheet that has been protected, with or without a password. When such a Worksheet is encountered your macro may well no longer work and display a Run Time Error.
One way that many do use is like shown below
Sub MyMacro() Sheet1.Unprotect Password:="Secret" 'YOUR CODE Sheet1.Protect Password:="Secret" End Sub
As you can see, the code un-protects Sheet1 with the password "Secret", runs the code and then password protects it again. This will work but has a number of drawbacks with one being that the code could bug out and stop before it encounters the Sheet1.Protect Password:="Secret" line of code. This of course would mean your Worksheet fully unprotected. The other problem is that you would need similar code for all Macros and all Worksheets.
UserInterFaceOnly
The UserInterFaceOnly is an optional argument of the Protect Method that we can set to True, the default is False. By setting this argument to True Excel will allow all Excel VBA macros to run on the Worksheet that protected with or without a password.
You need to be fully ware that, If you use the Protect method with the UserInterfaceOnly argument set to True on a Worksheet, then save the workbook, the entire worksheet (not just the interface) will be fully protected when you reopen the workbook. To set the user UserInterfaceOnly back to True after the workbook is opened, you must again apply the Protect method with UserInterfaceOnly set to True.
The solution to this is quite easy and requires us to make use of the Workbook_Open Event (fired as soon as the Workbook is opened) As this is an Event of the Workbook Object (ThisWorkbook) we must place the code as shown below in the Private Module of ThisWorkbook. To get here easily, right click on the Excel icon, top left next to "File" and select "View Code"
Private Sub Workbook_Open() 'If you have different passwords 'for each Worksheet. Sheets(1).Protect Password:="Secret", _ UserInterFaceOnly:=True Sheets(2).Protect Password:="Carrot", _ UserInterFaceOnly:=True 'Repeat as needed. End Sub
The above code is good if each Worksheet you need to have your macros operate on have different Passwords or your do not want to Protect all Worksheets. We can set the UserInterfaceOnly to True without having to un-protect first.
If you want to set the UserInterfaceOnly to True on all Worksheets and they have the same password you can use this code which must be placed in the same place as the above code.
Private Sub Workbook_Open() Dim wSheet As Worksheet For Each wSheet In Worksheets wSheet.Protect Password:="Secret", _ UserInterFaceOnly:=True
Next wSheet
End Sub
Now, each time you open the Workbook, the code will run and set the UserInterfaceOnly to True allowing your macros to operate while still prevent any changes from users.
See also:
See also: Index to Excel VBA Code; Index to Excel Freebies; Lesson 1 - Excel Fundamentals; Index to how to… providing a range of solutions
Click here to visit our Free 24/7 Excel/VBA Help Forum where there are thousands of posts you can get information from, or you can join the Forum and post your own questions.