Lock cells based on calculated value from another cell

Dedeke

Board Regular
Joined
Dec 1, 2020
Messages
70
Office Version
  1. 2016
Platform
  1. Windows
Hello need some help to achieve this.

In column U i have values "used" or "free" wich are calculated by a formula.
I would like to lock cells based on those 2 values.
Example: if U5 = "used" the cells E5 - I5 - M5 - Q5 should be locked. If the value from U5 should change into "free" those cells should be unlocked again.
This should happen for a range U4:U35 into the corresponding rows.

Many thx already
 

Excel Facts

Show numbers in thousands?
Use a custom number format of #,##0,K. Each comma after the final 0 will divide the displayed number by another thousand
Try the following code in your sheet events.

VBA Code:
Private Sub Worksheet_Change(ByVal Target As Range)
  Dim rng As Range, c As Range, rng2 As Range
  Dim lckd As Variant
  
  Set rng = Range("U4:U35")
  
  ActiveSheet.Unprotect
  
  If Not Intersect(Target, rng.Precedents) Is Nothing Then
    For Each c In rng
      Set rng2 = Range("E" & c.Row & ",I" & c.Row & ",M" & c.Row & ",Q" & c.Row)
      Select Case LCase(Range("U" & c.Row).Value)
        Case LCase("used"): lckd = True
        Case LCase("free"): lckd = False
        Case Else:          lckd = ""
      End Select
      If lckd <> "" Then rng2.Locked = lckd
    Next
  End If
  
  ActiveSheet.Protect
End Sub

NOTE SHEET EVENT
Right click the tab of the sheet you want this to work, select view code and paste the code into the window that opens up.​




----- --
Let me know the result and I'll get back to you as soon as I can.
Sincerely
Dante Amor
----- --
 
Upvote 0
@DanteAmor,

Thx for the verry quick response. Works like i want it to.
Is it possible to expand this for 2 more ranges??
Range V4:V34 should do the same with the columns F / J / N /R
Range W4:W34 ..... columns G / K /O /S
 
Upvote 0
Try this:

VBA Code:
Private Sub Worksheet_Change(ByVal Target As Range)
  Dim rngU As Range, rngV As Range, rngW As Range, c As Range, rng2 As Range
  Dim lckd As Variant
  
  ActiveSheet.Unprotect
  
  Set rngU = Range("U4:U35")
  If Not Intersect(Target, rngU.Precedents) Is Nothing Then
    For Each c In rngU
      Set rng2 = Range("E" & c.Row & ",I" & c.Row & ",M" & c.Row & ",Q" & c.Row)
      Select Case LCase(Range("U" & c.Row).Value)
        Case LCase("used"): lckd = True
        Case LCase("free"): lckd = False
        Case Else:          lckd = ""
      End Select
      If lckd <> "" Then rng2.Locked = lckd
    Next
  End If
  
  Set rngV = Range("V4:V35")      'Range V4:V34 ... columns F / J / N /R
  If Not Intersect(Target, rngV.Precedents) Is Nothing Then
    For Each c In rngV
      Set rng2 = Range("F" & c.Row & ",J" & c.Row & ",N" & c.Row & ",R" & c.Row)
      Select Case LCase(Range("V" & c.Row).Value)
        Case LCase("used"): lckd = True
        Case LCase("free"): lckd = False
        Case Else:          lckd = ""
      End Select
      If lckd <> "" Then rng2.Locked = lckd
    Next
  End If
  
  Set rngW = Range("W4:W35")      'Range W4:W34 ..... columns G / K /O /S
  If Not Intersect(Target, rngW.Precedents) Is Nothing Then
    For Each c In rngW
      Set rng2 = Range("G" & c.Row & ",K" & c.Row & ",O" & c.Row & ",S" & c.Row)
      Select Case LCase(Range("W" & c.Row).Value)
        Case LCase("used"): lckd = True
        Case LCase("free"): lckd = False
        Case Else:          lckd = ""
      End Select
      If lckd <> "" Then rng2.Locked = lckd
    Next
  End If
  
  ActiveSheet.Protect
End Sub


🫡
 
Upvote 0
Solution

Forum statistics

Threads
1,223,229
Messages
6,170,881
Members
452,364
Latest member
springate

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