how to locked and unlocked cells with protect sheets

Sian1

Board Regular
Joined
Nov 9, 2009
Messages
79
Hi,

Hoping some could help me. i was able to write the simple code with locked and unlocked cell based on a cell value however when i do a protect sheet function, it gave me an error "Run time Error "1004", unable to set the locked property on the range class"

basically here is the code
Private Sub worksheet_change(ByVal target As Range)
If Range("H10") = "Tier 3" Then
Range("H25:H29").Locked = True
Range("K10:K26").Locked = True
ElseIf Range("H10") = "Tier 1" Then
Range("H25:H29").Locked = False
Range("K10:K26").Locked = False
ElseIf Range("H10") = "Tier 2" Then
Range("H25:H29").Locked = False
Range("K10:K26").Locked = False
ElseIf Range("H10") = "Tier 4" Then
Range("H25:H29").Locked = True
Range("K10:K26").Locked = True
End If
End Sub


and i also have another question, in cell H13 there is a data validation function being used, drop down available for RT- with RI insurance and RT - with No RI Insurance however when the user select Tier 3 or Tier 4 in cell H10, it should only be the value - RT with NO RI insurance, how can i default that cell with the value when user select the Tier 3 or Tier 4.

thanks so much in advance
 

Attachments

  • pic 1.jpg
    pic 1.jpg
    118.2 KB · Views: 9
  • Capture.JPG
    Capture.JPG
    59.7 KB · Views: 9

Excel Facts

Did you know Excel offers Filter by Selection?
Add the AutoFilter icon to the Quick Access Toolbar. Select a cell containing Apple, click AutoFilter, and you will get all rows with Apple

DanteAmor

Well-known Member
Joined
Dec 3, 2018
Messages
14,835
Office Version
  1. 2010
Platform
  1. Windows
Try this

VBA Code:
Private Sub worksheet_change(ByVal target As Range)
  If target.Address = "$H$10" Then
    If target.CountLarge > 1 Then Exit Sub
    ActiveSheet.Unprotect
    Select Case target.Value
      Case "Tier 1", "Tier 2"
        Range("H25:H29").Locked = False
        Range("K10:K26").Locked = False
      Case "Tier 3", "Tier 4"
        Range("H25:H29").Locked = True
        Range("K10:K26").Locked = True
        Range("H13").Value = "RT with NO RI insurance"
    End Select
    ActiveSheet.Protect
  End If
End Sub
 

Sian1

Board Regular
Joined
Nov 9, 2009
Messages
79
Try this

VBA Code:
Private Sub worksheet_change(ByVal target As Range)
  If target.Address = "$H$10" Then
    If target.CountLarge > 1 Then Exit Sub
    ActiveSheet.Unprotect
    Select Case target.Value
      Case "Tier 1", "Tier 2"
        Range("H25:H29").Locked = False
        Range("K10:K26").Locked = False
      Case "Tier 3", "Tier 4"
        Range("H25:H29").Locked = True
        Range("K10:K26").Locked = True
        Range("H13").Value = "RT with NO RI insurance"
    End Select
    ActiveSheet.Protect
  End If
End Sub
Your are god send :) thanks so much
 

DanteAmor

Well-known Member
Joined
Dec 3, 2018
Messages
14,835
Office Version
  1. 2010
Platform
  1. Windows
I'm glad to help you. Thanks for the feedback.
 

Sian1

Board Regular
Joined
Nov 9, 2009
Messages
79

ADVERTISEMENT

Sorry may I trouble you how to set a password I want one ?
 

DanteAmor

Well-known Member
Joined
Dec 3, 2018
Messages
14,835
Office Version
  1. 2010
Platform
  1. Windows
Here an example:

Rich (BB code):
Private Sub worksheet_change(ByVal target As Range)
  If target.Address = "$H$10" Then
    If target.CountLarge > 1 Then Exit Sub
    ActiveSheet.Unprotect "abc"
    Select Case target.Value
      Case "Tier 1", "Tier 2"
        Range("H25:H29").Locked = False
        Range("K10:K26").Locked = False
      Case "Tier 3", "Tier 4"
        Range("H25:H29").Locked = True
        Range("K10:K26").Locked = True
        Range("H13").Value = "RT with NO RI insurance"
    End Select
    ActiveSheet.Protect "abc"
  End If
End Sub
 

Sian1

Board Regular
Joined
Nov 9, 2009
Messages
79

ADVERTISEMENT

thanks so much Dave and my apology for the late reply got so sick :(

so grateful for the help sure learnt a lot from you.
 

DanteAmor

Well-known Member
Joined
Dec 3, 2018
Messages
14,835
Office Version
  1. 2010
Platform
  1. Windows
I'm glad to help you. Thanks for the feedback.
 

Sian1

Board Regular
Joined
Nov 9, 2009
Messages
79
Hi Dave,

Quick question, how could I add when Tier 1 or Tier 2 with cell H13 = "RT - No Insurance" (please note this cell is a drop down list), cell K24:L24 will be locked. Appreciate your help. :)


Private Sub worksheet_change(ByVal target As Range)
If target.Address = "$H$10" Then
If target.CountLarge > 1 Then Exit Sub
ActiveSheet.Unprotect
Select Case target.Value
Case "Tier 1", "Tier 2"
Range("H25:H29").Locked = False
Range("K10:K26").Locked = False
Case "Tier 3", "Tier 4"
Range("H25:H29").Locked = True
Range("K10:K26").Locked = True
Range("H13").Value = "RT with NO RI insurance"
End Select
ActiveSheet.Protect
End If
End Sub
 

Sian1

Board Regular
Joined
Nov 9, 2009
Messages
79
I'm glad to help you. Thanks for the feedback.

Hi Dave,

Quick question, how could I add when Tier 1 or Tier 2 with cell H13 = "RT - No Insurance" (please note this cell is a drop down list), cell K24:L24 will be locked. Appreciate your help. :)


Private Sub worksheet_change(ByVal target As Range)
If target.Address = "$H$10" Then
If target.CountLarge > 1 Then Exit Sub
ActiveSheet.Unprotect
Select Case target.Value
Case "Tier 1", "Tier 2"
Range("H25:H29").Locked = False
Range("K10:K26").Locked = False
Case "Tier 3", "Tier 4"
Range("H25:H29").Locked = True
Range("K10:K26").Locked = True
Range("H13").Value = "RT with NO RI insurance"
End Select
ActiveSheet.Protect
End If
End Sub
 
Last edited by a moderator:
Master Excel Bundle

Excel contains over 450 functions, with more added every year. That’s a huge number, so where should you start? Right here with this bundle.

Forum statistics

Threads
1,164,630
Messages
5,838,463
Members
430,549
Latest member
jayjay2022

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