lock & unlock cells

davidhall80

Well-known Member
Joined
Jul 8, 2006
Messages
663
If cell A5 = accept, I want to lock range b5:g5
If cell A5 = change, I want to unlock range b5:g5


I need my sheet to update accordingly as i make changes. Does anyone know how to write this
 

Excel Facts

How to change case of text in Excel?
Use =UPPER() for upper case, =LOWER() for lower case, and =PROPER() for proper case. PROPER won't capitalize second c in Mccartney

Dufus

Board Regular
Joined
Aug 19, 2006
Messages
176
davidhall80,
Something like this?
Code:
Private Sub Worksheet_Change(ByVal Target As Range)
    If Target = Range("A5") Then
        If Target = "accept" Then Range("B5:G5").Locked = True
        If Target = "change" Then Range("B5:G5").Locked = False
    End If
End Sub
 

jindon

MrExcel MVP
Joined
Aug 21, 2004
Messages
16,995
try
Code:
Private Sub Worksheet_Change(ByVal Target As Range)
Dim x As Boolean
With Target
   If .Address(0,0) <> "A5" Then Exit Sub
   If .Count>1 Then Exit Sub
   Select Case UCase(.Value)
      Case "ACCEPT" : x = True
      Case "CHANGE" : x = False
      Case Else : Exit Sub
   End Select
End With
   Range("b5:g5).Locked = x
End Sub
 

jindon

MrExcel MVP
Joined
Aug 21, 2004
Messages
16,995

ADVERTISEMENT

thaanks buddy. worked like a charm

Are you sure?

The line

Target = Range("a5") means

If Target.Value = Range("a5").Value

is this what you wanted?
 

Dufus

Board Regular
Joined
Aug 19, 2006
Messages
176
You bet. Just a small change if you need to accomodate the possiblility that someone selects more than one cell at a time:
Code:
Private Sub Worksheet_Change(ByVal Target As Range)
    If Target.Cells.Count > 1 Then Exit Sub
    If Target = Range("A5") Then
        If Target = "accept" Then Range("B5:G5").Locked = True
        If Target = "change" Then Range("B5:G5").Locked = False
    End If
End Sub
 

jindon

MrExcel MVP
Joined
Aug 21, 2004
Messages
16,995

ADVERTISEMENT

You bet. Just a small change if you need to accomodate the possiblility that someone selects more than one cell at a time:
Code:
Private Sub Worksheet_Change(ByVal Target As Range)
    If Target.Cells.Count > 1 Then Exit Sub
    If Target = Range("A5") Then
        If Target = "accept" Then Range("B5:G5").Locked = True
        If Target = "change" Then Range("B5:G5").Locked = False
    End If
End Sub

Change in any cell to Range("a5").Value will execute the code all the way
because the line of

If Target = Range("A5")
 

Dufus

Board Regular
Joined
Aug 19, 2006
Messages
176
Hi Jindon,

You're right. That's weird because it does work. Your's handles the case that the range isn't just one cell as well as if the word isn't typed in lower case. Thanks for the upgrade.

Dufus
 

jindon

MrExcel MVP
Joined
Aug 21, 2004
Messages
16,995
Hi Jindon,

You're right. That's weird because it does work. Your's handles the case that the range isn't just one cell as well as if the word isn't typed in lower case. Thanks for the upgrade.

Dufus
If you don't mind about unneeded execution of whole code, Yes it does in this case.

But you can't do like

If Target = Range("a5:a10")

Do you understand what I mean?
 

davidhall80

Well-known Member
Joined
Jul 8, 2006
Messages
663
can this be done with radio buttons. lets say i had two radio buttons. One to lock that range. one to unlock it, how would that code look?
 

Forum statistics

Threads
1,136,700
Messages
5,677,280
Members
419,683
Latest member
MrVBAConfused

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
Top