VBA to lock each worksheet in a workbook

XLBob

Board Regular
Joined
Aug 17, 2012
Messages
65
I have below code to protect each sheet in a workbook. However when I run this, it only protects the first one. The for loop doesn't work for some reason. Anyone knows why?
Code:
Sub Macro1()
'
' Macro1 Macro
'

Dim sh As Worksheet
For Each sh In ActiveWorkbook.Worksheets
    Cells.Select
    Selection.Locked = False
    Selection.FormulaHidden = False
    Selection.SpecialCells(xlCellTypeFormulas, 23).Select
    Selection.Locked = True
    Selection.FormulaHidden = False
    ActiveSheet.Protect DrawingObjects:=True, Contents:=True, Scenarios:=True _
        , AllowSorting:=True, AllowUsingPivotTables:=True, Password:="123"
    ActiveSheet.EnableSelection = xlUnlockedCells
  
Next sh
End Sub
 
Last edited by a moderator:

Excel Facts

Select all contiguous cells
Pressing Ctrl+* (asterisk) will select the "current region" - all contiguous cells in all directions.
Your code locks the active sheet, but never activates any sheet. However you don't need to activate any if you use this:
Code:
Sub Macro1()
'
' Macro1 Macro
'

Dim sh As Worksheet
For Each sh In ActiveWorkbook.Worksheets
   With sh.Cells
    .Locked = False
    .FormulaHidden = False
    On Error Resume Next
    with .SpecialCells(xlCellTypeFormulas, 23)
      .Locked = True
      .FormulaHidden = False
    end with
    On Error goto 0
   end with
   sh.Protect DrawingObjects:=True, Contents:=True, Scenarios:=True _
        , AllowSorting:=True, AllowUsingPivotTables:=True, Password:="123"
    sh.EnableSelection = xlUnlockedCells
  
Next sh
End Sub
 
Upvote 0
On which line? It shouldn't be possible given the error handler unless you have set your VB Editor to break on all errors and you don't have any formulas on one of the sheets.
 
Upvote 0

Forum statistics

Threads
1,214,924
Messages
6,122,294
Members
449,077
Latest member
Rkmenon

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