VBA to lock cell not preventing user from selecting.

JimS63

New Member
Joined
Dec 8, 2020
Messages
21
Office Version
  1. 365
Platform
  1. Windows
I have a sheet that has four input columns. They are as follows

Height Width Diameter 1 Diameter 2

Only one pair can be used at a time, either Height and Width or Diameter 1 and Diameter 2

I have a script that will lock the cells of the opposite pair anytime a value is placed in one of the pairs. For instance if you put a value in Height it will change the cell property for Diameter 1 and Diameter 2 to locked.

This is working correctly, however I can still tab into the cell. I want a tab to skip that cell.
I know that there is a simple variable I am missing, can anyone help point it out for me?

Thanks in advance

VBA Code:
Private Sub Worksheet_Change(ByVal Target As Range)
ActiveSheet.Unprotect
    If Range("B6").Value >= 1 Then
        ActiveSheet.Range("D6:E35").Locked = True
    ElseIf Range("B6").Value < 1 Then
        ActiveSheet.Range("D6:E35").Locked = False
    End If
    
        If Range("D6").Value >= 1 Then
        ActiveSheet.Range("B6:C35").Locked = True
    ElseIf Range("D6").Value < 1 Then
        ActiveSheet.Range("B6:C35").Locked = False
    End If
        ActiveSheet.Protect Contents:=True
  End Sub
 

Excel Facts

How to fill five years of quarters?
Type 1Q-2023 in a cell. Grab the fill handle and drag down or right. After 4Q-2023, Excel will jump to 1Q-2024. Dash can be any character.
Hi & welcome to MrExcel.
Add this just before the End Sub
VBA Code:
    Me.EnableSelection = xlUnlockedCells
 
Upvote 0

Forum statistics

Threads
1,215,409
Messages
6,124,733
Members
449,185
Latest member
hopkinsr

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