How to prevent users to change cells but allow VBA to change them

3

2

I'm using a Excel spreadsheet to record staff resource. In column B, there is a value of "Enter your name", which instructs the user where to start entering their information. Then, when the user enters their details in this row, the next row is populated with the pre-defined text.

Unfortunately, I have some users who are unable to follow such a simple instruction and start to enter their details into any row.

How can I adapt the following code so that any blank rows in column B are locked but still allow VBA to populate the appropriate cell with "Enter your name"?

This is a piece of code which creates the text value:

With Target 
    Select Case True              
    Case .Column = 2 
        If .Value2 <> "Enter your name" And .Offset(, -1) = "" Then                  
            Set FirstBlankCell = Range("B" & Rows.Count).End(xlUp).Offset(1, 0) 
            FirstBlankCell.Value = "Enter your name" 
        End If 
    Case Else 
    End Select 
End With 

IRHM

Posted 2013-02-02T18:32:00.563

Reputation: 195

Answers

3

You could just check for the existence of your default vba-entered text string in a cell in the targeted column whenever the user changes the contents of a cell on the worksheet, and if it is found either alert the user, or move what they entered into the cell it should have been entered into (both actions are in the code below, (the Move option is commented out in the IF ELSE block):

Const USER_ENTRY_COL = 2                    'Column users should be entering data into
Const TARGET_TEXT = "Enter your name here"  'The default text the VBA code uses to mark the correct cell
Const ENTRY_ROW_NOT_FOUND = -1            'Return value for correct cell search if correct cell cannot be found

Private Sub Worksheet_Change(ByVal Target As Range)
    'do not test if not in user entry column
    If Target.Column <> USER_ENTRY_COL Then Exit Sub

    'do nothing if first cell of target range is empty or is target text,
    'which it would be if macro is flagging cell for user
    If Target.Cells(1, 1).Value = "" Or Target.Cells(1, 1).Value = TARGET_TEXT Then Exit Sub

    Dim rowWithDefaultText As Long
    rowWithDefaultText = find_row_with_default_text(USER_ENTRY_COL)

    If rowWithDefaultText = ENTRY_ROW_NOT_FOUND Then
        'user has overwitten the vba inserted default text,meaning they entered in the right row
    Else
        'Alerts the user and clears what they entered into the wrong cell
        MsgBox "Please enter your information into row " & rowWithDefaultText, vbInformation, "Data Entered in Wrong Row"
        Target.Clear
        Cells(rowWithDefaultText, USER_ENTRY_COL).Activate

''        'Moves whatever the user entered, from the wrong cell into the right cell
''        Dim name As Variant
''        name = Target.Cells(1, 1).Value
''        Target.Clear
''        Cells(rowWithDefaultText, USER_ENTRY_COL).Value = name
    End If
End Sub

'//Finds the correct row that is meant to be used for user entry
'@PARAM colNum - The column number for the column to be searched
Private Function find_row_with_default_text(colNum As Integer) As Long
    Dim CorrectEntryRow As Long
    CorrectEntryRow = find_first_instance_row(TARGET_TEXT, USER_ENTRY_COL, 1, 500)
    find_row_with_default_text = CorrectEntryRow
End Function


'//Cannot be found in the range, then a row value of '-1' will be returned
'@PARAM searchTerm - The value to find the first instance of
'@PARAM colNum - The column number for the column to be searched
'@PARAM startRow - The row number for the top of the range to be searched
'@PARAM endAtRow - The row number for the end of the range to be searched
Public Function find_first_instance_row(ByVal searchterm As String, _
                        ByVal colNum As Integer, ByVal startAtRow As Long, _
                        ByVal endAtRow As Long) As Long
    Dim searchRange As Range
    Set searchRange = Range(Cells(startAtRow, colNum), Cells(endAtRow, colNum))
    Dim foundIt As Range
    Set foundIt = searchRange.Find(searchterm, , , xlWhole)
    If Not foundIt Is Nothing Then
        find_first_instance_row = foundIt.Row
    Else
        'force bad value when not found this makes returned value easily testable
        find_first_instance_row = -1
    End If

    Set searchRange = Nothing
    Set foundIt = Nothing
End Function

The above assumes that the vba-inserted text was there prior to the user entering their name; if for some reason it was not, then there is no test to make sure user did not enter their name 2,3, 10 rows down. If you wanted to add a test that case occurring, the IF ELSE could be modified to look something like:

If rowWithDefaultText = ENTRY_ROW_NOT_FOUND Then
    'user has overwitten that text in the cell that had the text prior

    'Secondary check added
    If Not entry_row_and_correct_row_match(USER_ENTRY_COL, 1, Target.Row) Then
        MsgBox "Do Something Here to handle this case"
    End If
Else
    'Alerts the user and clears what they entered into the wrong cell
    MsgBox "Please enter your information into row " & rowWithDefaultText, vbInformation, "Data Entered in Wrong Row"
    Target.Clear
    Cells(rowWithDefaultText, USER_ENTRY_COL).Activate

''        'Moves whatever the user entered, from the wrong cell into the right cell
''        Dim name As Variant
''        name = Target.Cells(1, 1).Value
''        Target.Clear
''        Cells(rowWithDefaultText, USER_ENTRY_COL).Value = name
End If

And add the following 2 functions to support that secondary test:

'//Checks the last populated cell in a continuous range moving
'//down the worksheet against the row number passed in 'entryRow'
'//to see if they are a match
'@PARAM colNum - The column number for the column to be searched
'@PARAM startRow - The row at which to begin the search
'@PARAM entryRow - The row to test against
Private Function entry_row_and_correct_row_match(ByVal colNum As Integer, _
                ByVal startRow As Long, ByVal entryRow As Long) As Boolean
    Dim correctRow As Long
    correctRow = find_last_xlDown_row(colNum, 1)
    entry_row_and_correct_row_match = (entryRow = correctRow)
End Function

'//Finds the last populated cell going down a row, beginning on the
'//starting row number you provide.
'//ASSUME:Range is continuous in the targeted column!
'@PARAM colNum - The column number for the column to be searched
'@PARAM startRow - The row at which to begin the search
Public Function find_last_xlDown_row(ByVal colNum As Integer, _
                                        ByVal startRow As Long) As Long
    find_last_xlDown_row = Cells(startRow, colNum).End(xlDown).Row
End Function

BTW, you may want to consider changing the vba-inserted text to read "Enter your name here"; Adding that one word may cut down on the number of instances you see this issue.

Note: All of this code can go into the worksheet's code page.

Hope this helps, Nim

nim

Posted 2013-02-02T18:32:00.563

Reputation: 46

Hi @nim, thank you for taking the time to reply to my post and for putting the solution together, it's fantastic. I really can't thank you enough for all the time and effort you've clearly put in. Kind regards and once again many thanks. Chris – IRHM – 2013-02-03T13:42:15.780

3

Why not using sheet protection and VBA together?

  1. Select your cell or column you want to be editable
  2. Press CTRL+1 » Go to tab Protection » uncheck locked
  3. Menu Bar » Tools » Protection » Protect sheet » ok (do not enter a password)

    enter image description here

Now every user who opens your workbook is only allowed to enter data in your selected cells or columns. If you want to allow the user to edit everywhere after he has entered his name, you could use this VBA code

Private Sub Worksheet_SelectionChange(ByVal Target As Range)
    If Sheets(1).Cells(2, 1).Value <> "Enter your name" Then
        Sheets(1).Unprotect
    Else
        Sheets(1).Protect
    End If
End Sub

With every selection change (entering cell data is automatically combined with a selection change), the code checks if the string "Enter your name" in cell A1 has changed. If yes, the protection gets disabled.

nixda

Posted 2013-02-02T18:32:00.563

Reputation: 23 233

Hi @nixda, thank you for taking the time to reply to my post and for the solution. Although, I don't want to lock the whole sheet, this will give me something to work with. Kind regards. Chris – IRHM – 2013-02-03T13:40:38.167