[VBA]

HiIamMason

New Member
Joined
Dec 18, 2019
Messages
4
Office Version
  1. 365
Platform
  1. Windows
Hello Friends,

I am new to VBA and i have trying to set a code up that does the following.

If values are entered in any given row of column F. all the columns in that given row will be locked and protected.

VBA Code:
Private Sub Worksheet_Change(ByVal Target As Range)
Set Rng = Range("F2:F999999")
If Sheets("Sheet1").ProtectContents = True Then Sheets("Sheet1").Unprotect Password:="myPass"
For Each cell In Rng
If WorksheetFunction.CountA(Range("rng")) = 0 Then
Else
If Sheets("Sheet1").ProtectContents = True Then Sheets("Sheet1").Unprotect Password:="myPass"
Range("A2:E6").Locked = True
End If
Sheets("Sheet1").Protect Password:="myPass", UserInterfaceOnly:=True
End Sub

I know it does not look pretty, hope somebody is able to help me.
 
Last edited by a moderator:

Excel Facts

Back into an answer in Excel
Use Data, What-If Analysis, Goal Seek to find the correct input cell value to reach a desired result
Assuming that you are just trying to lock columns A:E in the row where you are entering a value for column F, try this code:
VBA Code:
Private Sub Worksheet_Change(ByVal Target As Range)

    Dim r As Long

'   Exit if multiple cells updated at once
    If Target.CountLarge > 1 Then Exit Sub
    
'   Only run if column F updated
    If Target.Column = 6 Then
        If Sheets("Sheet1").ProtectContents = True Then Sheets("Sheet1").Unprotect Password:="myPass"
'       Lock columns A:E in that row
        r = Target.Row
        Range(Cells(r, "A"), Cells(r, "E")).Locked = True
        Sheets("Sheet1").Protect Password:="myPass", UserInterfaceOnly:=True
    End If

End Sub
 
Upvote 0

Forum statistics

Threads
1,216,113
Messages
6,128,905
Members
449,478
Latest member
Davenil

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