VBA Macro to Protect Multiple Sheets in a Workbook (142111)



The information in this article applies to:

  • Microsoft Excel for Windows 95
  • Microsoft Excel for the Macintosh 5.0

This article was previously published under Q142111

SUMMARY

In Microsoft Excel, individual worksheets can only be protected one sheet at a time. It is not possible to protect multiple worksheets in a single step. However, you can use Microsoft Visual Basic for Applications code to protect multiple sheets through a looping procedure that can accept various degrees of user input.

MORE INFORMATION

Microsoft provides programming examples for illustration only, without warranty either expressed or implied. This includes, but is not limited to, the implied warranties of merchantability or fitness for a particular purpose. This article assumes that you are familiar with the programming language that is being demonstrated and with the tools that are used to create and to debug procedures. Microsoft support engineers can help explain the functionality of a particular procedure, but they will not modify these examples to provide added functionality or construct procedures to meet your specific requirements. The following sample Visual Basic macro unconditionally protects all sheets in a workbook, without user intervention and without a password.

Sample Visual Basic Procedure

 Sub Protect_Example1()

      ' Loop through all sheets in the workbook.
      For i = 1 To Sheets.Count
         Sheets(i).Protect
      Next i

   End Sub
				
This example prompts you to determine if you want to protect the current sheet. If you answer yes, the sheet is then protected with a hard-coded password.
   Sub Protect_Example2()

      ' Loop through all sheets in the workbook
      For i = 1 To Sheets.Count

         ' Activate each sheet in turn.
         Sheets(i).Activate

         response = MsgBox("Do you want to protect this sheet?", vbYesNo)
         If response = vbYes Then
            ActiveSheet.Protect password:="larry", DrawingObjects:=True, _
               Contents:=True, Scenarios:=True

         ElseIf response = vbNo Then
            MsgBox ("Sheet not protected")

         End If
      Next i
   End Sub
				

Additional Options You Can Use To Protect Specific Sheet Types

To protect only Worksheets:
   For i = 1 To Worksheets.Count
        Worksheets(i).Activate
				
To protect only module sheets:
   For i = 1 To Modules.Count
      Modules(i).Activate
				
To protect only chart sheets:
   For i = 1 To Charts.Count
      Charts(i).Activate
				
To protect only Dialog sheets:
      For i = 1 To DialogSheets.Count
      DialogSheets(i).Activate
				

REFERENCES

"Microsoft Excel User's Guide," version 5.0, pages 683-689

Modification Type:MinorLast Reviewed:10/11/2006
Keywords:kbdtacode kbhowto KB142111