Use VBA to lock cells in workbook

Swivs

New Member
Joined
Sep 2, 2014
Messages
5
Hi, I have a spreadsheet that has a mix of locked and unlocked cells. It will be protected so that people can select, but not edit locked cells and I would like it so that after a certain date, the code locks all the cells, or makes it so that people can't select any cells in the entire workbook. So far I have this:

Private Sub Workbook_Open()
If Sheets(1).Cells(2, 2).Value <= Date Then
Dim ws As Worksheet
Dim pwd As String
pwd = "password"
For Each ws In Worksheets
ws.Protect Password:=pwd
Next ws
MsgBox "This workbook is locked, please contact nobody@nowhere.com"
Else
'MsgBox "unlocked"
End If
End Sub


This works to protect all the worksheets, however I can't find a way to lock all cells

Thanks in advance for any help!
 

Excel Facts

When they said...
When they said you are going to "Excel at life", they meant you "will be doing Excel your whole life".
Try

Code:
For Each ws In Worksheets
    ws.Cells.Locked = True
    ws.Protect Password:=pwd
Next ws
 
Upvote 0
No, that didn't work.. I got:

Run-time error '1004':
Unable to set the locked property of the range class
 
Upvote 0
Try

Code:
Private Sub Workbook_Open()
Dim ws As Worksheet
Dim pwd As String
pwd = "password"
If Sheets(1).Cells(2, 2).Value <= Date Then
    For Each ws In Worksheets
        ws.Unprotect Password:=pwd
        ws.Cells.Locked = True
        ws.Protect Password:=pwd
    Next ws
    MsgBox "This workbook is locked, please contact nobody@nowhere.com"
Else
    'MsgBox "unlocked"
End If
End Sub
 
Upvote 0

Forum statistics

Threads
1,214,821
Messages
6,121,759
Members
449,048
Latest member
excelknuckles

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