How to select all unlocked cells in Excel

Spreadsheets are easy to break.  All it takes is one press of a key and suddenly every formula is displaying in an error message.  That’s not good!  This is why we apply worksheet protection, to prevent user error.

Some think that worksheet protection is secure, however password protected worksheets can easily be unlocked with a macro.  Therefore, any user who really wants to break our spreadsheet can.  The real benefit of protection is therefore, not to lock down the worksheet, but to prevent basic user error.

Allow users to change cells when worksheet is protected

We can protect an entire worksheet.  But we can also set specific cells to be unlocked, this enables the user to interact only with the parts of the worksheet that we want them to.

Whilst the worksheet is unlocked, click on any Cell and open the Format Cells window.  On the Protection tab there is the option to lock or unlock the Cell.

Format Cells - lock and unlock

To apply this with VBA we could use the following code:

Sub UnlockSelectedCells()

Selection.Locked = False

End Sub

Or to reverse it back to locked

Sub LockSelectedCells()

Selection.Locked = True

End Sub

How to select all unlocked cells

But here is the challenge, without going through every cell, how do we know which are locked or unlocked?  What if we want to apply formatting to only the unlocked cells how could we do that easily?

The Go To Special… menu has a lot of good selection options, but selecting unlocked cells is not one of them.

It’s possible to tab through unlocked cells when the worksheet is protected, but that can be time consuming and not particularly convenient.

It’s much faster to apply some VBA to select only the unlocked cells.

The following code will select all the unlocked cells:

  • from the used range of the worksheet if only one cell is selected
  • from the selected range  if more than one cell is selected.
Sub SelectAllUnlockedCells()

Dim c As Range
Dim unlockedCells As Range
Dim fullRange As Range
Dim rangeDescription As String

'Count cells in selection .If 1 cell then search used range
'otherwise search the selected range
If Selection.Cells.Count > 1 Then
    Set fullRange = Selection
    rangeDescription = "selected cells"
Else
    Set fullRange = ActiveSheet.UsedRange
    rangeDescription = "active range"
End If

'Loop through each cell in the chosen range of active sheet
For Each c In fullRange

    If c.Locked = False Then

        'If find first cell set the variable, otherwise add
        'to existing list of cells
        If unlockedCells Is Nothing Then
            Set unlockedCells = c
        Else
            Set unlockedCells = Union(unlockedCells, c)
        End If

    End If

Next

'Select the range of unlocked cells
If Not unlockedCells Is Nothing Then
    unlockedCells.Select
Else

    MsgBox "There are no unlocked cells in the " _
        & rangeDescription & ": " & fullRange.Address
End If

End Sub

And that’s it.  Simple right.

The code will also work with protected worksheets, provided the protection settings applied allow the selection of unlocked cells.

All Select Unlocked Cells

Conclusion

If you regularly build Excel models and applications for other to use, this macro can save you time and reduce errors.  Add this code to a standard module inside your Personal Macrobook to ensure it’s always available when you need it.

2 thoughts on “How to select all unlocked cells in Excel”

Leave a Comment