This macro allows you to have a cell automatically locked after a user enters something into it or into another specific cell, range, column, or row.
This is different than just locking an entire spreadsheet because you still want to be able to edit and work with the other cells in the worksheet without having to select and unlock them individually.
Lock Cell Other Than the One that was Edited
Lock Cell in a Specific Column or Row
The first thing you have to do is to unlock all of the cells in the worksheet.
Now, none of the cells in the worksheet are protected, which means that all of the cells in the worksheet will be editable when you go to protect the worksheet.
This needs to be done so that only specific cells that we choose will be locked from editing.
Private Sub Worksheet_Change(ByVal Target As Range)
If Target.Address = "$A$1" And Target.Value <> "" Then
ActiveSheet.Protect Contents:=False
Range(Target.Address).Locked = True
ActiveSheet.Protect Contents:=True
End If
End Sub
The important code is this part:
ActiveSheet.Protect Contents:=False
Range(Target.Address).Locked = True
ActiveSheet.Protect Contents:=True
It unprotects the worksheet, locks the cell, and then re-protects the sheet.
This macro needs to be installed into the worksheet where it will run. To do this, right-click the tab of the desired worksheet and click View Code and paste the macro into the window that opens.
This example is a generic example that is easy to modify. It checks which cell was edited and, if a certain cell was edited, it is then locked.
I will show you how to edit this macro in the examples below.
Looking at the macro above, this is the line that limits the macro to run only on specific cells:
If Target.Address = "$A$1" And Target.Value <> "" Then
This says that a cell should be locked only if cell A1 was edited and it is not empty.
To make the macro work on cell B1 or D15 or any cell, just replace $A$1 with the desired cell reference. You must put dollar signs in front of the column and row reference for this to work.
You can also lock the cell only if a certain value was input by changing <> "" in the line above to = "desired value" and that allows you to do something like lock the cell only if OK was entered or something similar.
Change this line:
Range(Target.Address).Locked = True
Target.Address is the cell that will be locked and this says to lock the cell that was just edited.
To lock another cell, just use the Range method of referencing cells.
To lock cell B5, it would be Range(B5).Locked = True
Continue that pattern for whichever cell or range you want to lock.
You can lock the last edited cell regardless of which one it was by removing the IF statement in the macro and leaving it like this:
Private Sub Worksheet_Change(ByVal Target As Range)
ActiveSheet.Protect Contents:=False
Range(Target.Address).Locked = True
ActiveSheet.Protect Contents:=True
End Sub
To limit the locking to a certain column or row, change the IF statement.
If Target.Row = 1 And Target.Value <> "" Then
Change the 1 to whichever row you want and the code will only run on that row.
If Target.Column = 1 And Target.Value <> "" Then
Change the 1 to whichever column you want the code to run on.
This is a handy macro that allows you to have a lot of control over a worksheet and protecting the data within it.
I didn't show you how to password protect the worksheet here because I wanted to focus on the method needed to protect only specific cells. Once you get this form of the macro running well, then, add-in the other pieces that you want, like password protection.
Make sure to download the sample file attached to this tutorial so you can work with these examples in Excel.