VBA stops working when locking the worksheet

Ironhan

New Member
Joined
Jul 22, 2020
Messages
10
Office Version
  1. 2016
Platform
  1. Windows
Hi all,

I have a worksheet with a range of cells containing names (F4:H5) and upon clicking the cell from the range, the cell value(name) gets copied and pasted to B4:B9.

Then the adjacent columns (C4:C9 and D4:D9) do vlookup to look up the age and score from the reference range (F15:H20).

Lastly, I have a clear button(B20) which clears B4:B9 on click.

The problem I'm having is, I need the range C4:D9 and F15:H20 to be locked, but when I try to do so, the VBA stops working properly.

I've tried to lock the worksheet with all the cell unprotected but doesn't seem to work either way.

Any inputs on how to fix this would be much appreciated.

Below is the link to the worksheet and the code I used.

Thanks!



VBA Code:
Private Sub Worksheet_SelectionChange(ByVal Target As Range)
   If Target.CountLarge > 1 Then Exit Sub
   If Not Intersect(Target, Range("F4:H5")) Is Nothing Then
      On Error GoTo Oops
      Target.Copy Range("B4:B9").SpecialCells(xlBlanks)(1)
      On Error GoTo 0
   ElseIf Target.Address(0, 0) = "B20" Then
      Range("B4:B9").ClearContents
   End If
   Exit Sub
Oops:
   MsgBox "No space available"
End Sub
 

Excel Facts

What is the fastest way to copy a formula?
If A2:A50000 contain data. Enter a formula in B2. Select B2. Double-click the Fill Handle and Excel will shoot the formula down to B50000.
How about
VBA Code:
Private Sub Worksheet_SelectionChange(ByVal Target As Range)
   If Target.CountLarge > 1 Then Exit Sub
   Me.Unprotect "Password"
   If Not Intersect(Target, Range("F4:H5")) Is Nothing Then
      On Error GoTo Oops
      Target.Copy Range("B4:B9").SpecialCells(xlBlanks)(1)
      On Error GoTo 0
   ElseIf Target.Address(0, 0) = "B20" Then
      Range("B4:B9").ClearContents
   End If
   Me.Protect "Password"
   Exit Sub
Oops:
   MsgBox "No space available"
   Me.Protect "Password"
End Sub
Change Password to suit.
 
Upvote 0

Forum statistics

Threads
1,213,546
Messages
6,114,256
Members
448,558
Latest member
aivin

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