How to select all unlocked cells in Excel

Select locked cells

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
100 Excel VBA Macros

Do you know the fastest way to learn foreign languages?  It is to read, write, speak, and think in that language as often as possible.  Apart from speaking, programming languages are no different.  The more you immerse yourself in that language, the faster you will pick it up.

100 Excel Macros Book

Therefore, what most people like you need is lots of examples that you can practice.  That is why the 100 Excel VBA Macros eBook exists.  It’s the book for all Excel users who want to learn how to read and write Excel macros, save time, and stand out from their peers.  The book contains:

  • 100 example codes to practice reading and writing macros that will embed the language into your thinking.
  • An introduction to macros in Excel to ensure you can implement the VBA code in the book even if you have no prior knowledge.
  • Consistent code layout between examples to enable you to understand the structure and easily customize the code to meet your needs.
  • Downloadable workbook containing all the source code, so the examples can be added to your project to give you the benefit of VBA straight away.

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.



Get our FREE VBA eBook of the 30 most useful Excel VBA macros.
Automate Excel so that you can save time and stop doing the jobs a trained monkey could do.

Email Address * First Name *

By entering your email address you agree to receive emails from Excel Off The Grid. We’ll respect your privacy and you can unsubscribe at any time.


Don’t forget:

If you’ve found this post useful, or if you have a better approach, then please leave a comment below.

Do you need help adapting this to your needs?

I’m guessing the examples in this post didn’t exactly meet your situation.  We all use Excel differently, so it’s impossible to write a post that will meet everybody’s needs.  By taking the time to understand the techniques and principles in this post (and elsewhere on this site) you should be able to adapt it to your needs.

But, if you’re still struggling you should:

  1. Read other blogs, or watch YouTube videos on the same topic.  You will benefit much more by discovering your own solutions.
  2. Ask the ‘Excel Ninja’ in your office.  It’s amazing what things other people know.
  3. Ask a question in a forum like Mr Excel, or the Microsoft Answers Community.  Remember, the people on these forums are generally giving their time for free.  So take care to craft your question, make sure it’s clear and concise.  List all the things you’ve tried, and provide screenshots, code segments and example workbooks.
  4. Use Excel Rescue, who are my consultancy partner.   They help by providing solutions to smaller Excel problems.

What next?
Don’t go yet, there is plenty more to learn on Excel Off The Grid.  Check out the latest posts:

Leave a Reply

Your email address will not be published. Required fields are marked *