Please Note: This article is written for users of the following Microsoft Excel versions: 2007, 2010, 2013, 2016, 2019, and Excel in Office 365. If you are using an earlier version (Excel 2003 or earlier), this tip may not work for you. For a version of this tip written specifically for earlier versions of Excel, click here: Visually Showing a Protection Status.

Visually Showing a Protection Status

by Allen Wyatt
(last updated July 11, 2015)

1

Todd has developed a workbook used by others. To prevent data from being ruined, he's protected the worksheet as well as the workbook. The problem is, Todd sometimes forgets to protect the worksheet and workbook after making changes. He is wondering if there is a way to create a visual indicator that shows whether the worksheet/workbook is currently protected or unprotected.

Of course, the easiest way to check to see if something is unprotected is to just start looking at the tools on the various ribbon tabs. If the full range of tools is there, then the worksheet and workbook are unprotected. If there are significant numbers of tools that are unavailable ("grayed out"), then protection is turned on.

Another easy solution is to create a user-defined function that returns a value indicating whether the workbook or worksheet are protected. The following will do the trick:

Function WksProtected(rng As Range) As String
    Application.Volatile
    If rng.Parent.ProtectContents Then
        WksProtected = "Protected"
    Else
        WksProtected = "Not Protected"
    End If
End Function
Function WkbProtected(rng As Range) As String
    Application.Volatile
    If rng.Parent.Parent.ProtectStructure Then
        WkbProtected = "Protected"
    Else
        WkbProtected = "Not Protected"
    End If
End Function

To use the macros, just include formulas like the following anywhere in the worksheet:

=WksProtected(A1)
=WkbProtected(A1)

The result of the formulas is either "Protected" or "Not Protected," depending on the state of the worksheets and workbook. You could use conditional formatting to highlight the cells based on what is returned by the functions.

Remember: The value from the functions is only updated if the worksheet is recalculated. If all you do is protect (or unprotect) the worksheet, that doesn't result in the worksheet being recalculated. So to see the proper results after changing the protection status, you'll need to make sure you recalculate the worksheet.

Note:

If you would like to know how to use the macros described on this page (or on any other page on the ExcelTips sites), I've prepared a special page that includes helpful information. Click here to open that special page in a new browser tab.

ExcelTips is your source for cost-effective Microsoft Excel training. This tip (9639) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, and Excel in Office 365. You can find a version of this tip for the older menu interface of Excel here: Visually Showing a Protection Status.

Author Bio

Allen Wyatt

With more than 50 non-fiction books and numerous magazine articles to his credit, Allen Wyatt is an internationally recognized author. He is president of Sharon Parq Associates, a computer and publishing services company. ...

MORE FROM ALLEN

Specifying the Number of Worksheets in a New Workbook

By default, a new Excel workbook contains three blank worksheets. You can (and should) configure Excel to whatever number ...

Discover More

Moving the Taskbar to a Different Edge of the Screen

The Taskbar is normally displayed along the bottom edge of the screen. Windows gives you the flexibility to decide where ...

Discover More

Declaring Variables

Macros depend on the use of variables to do their work. This tip examines how variables are declared in a macro, using ...

Discover More

Professional Development Guidance! Four world-class developers offer start-to-finish guidance for building powerful, robust, and secure applications with Excel. The authors show how to consistently make the right design decisions and make the most of Excel's powerful features. Check out Professional Excel Development today!

More ExcelTips (ribbon)

Password Protecting Specific Columns in a Worksheet

When you are developing a worksheet for others to use, you might want to protect some of the information in that ...

Discover More

Stopping a Worksheet from being Moved or Copied

Want to stop a user from moving or copying a worksheet? This task (like many) can be more complex than one would hope. ...

Discover More

Protecting Many Worksheets

Need to protect a lot of worksheets? Rather than protect the sheets individually, you'll appreciate the macros discussed ...

Discover More
Subscribe

FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."

View most recent newsletter.

Comments

If you would like to add an image to your comment (not an avatar, but an image to help in making the point of your comment), include the characters [{fig}] in your comment text. You’ll be prompted to upload your image when you submit the comment. Maximum image size is 6Mpixels. Images larger than 600px wide or 1000px tall will be reduced. Up to three images may be included in a comment. All images are subject to review. Commenting privileges may be curtailed if inappropriate images are posted.

What is 3 - 0?

2019-03-01 13:07:30

J. Woolley

Here's a generalized version of the UDF described in the Tip. (Apologies for poor VBA code format when posting comments here.)

Public Function IsProtected(Optional ByVal Target As Range = Nothing, Optional ByVal Choice As Variant = 0) As Variant
'
' User-Defined Function (UDF) to return the protection status (True or False) of Target's Worksheet or Workbook
' Default Target is the cell referencing this function (error if referenced in a VBA statement)
' Default Choice is 0 (or "contents")
' If Choice = 3 or "scenarios" return True if the Worksheet's scenarios are protected
' If Choice = 2 or "interface" return True if the Worksheet's user interface is protected (but not its macros)
' If Choice = 1 or "shapes" return True if the Worksheet's shapes are protected
' If Choice = 0 or "contents" return True if the Worksheet's contents are protected (this is the default Choice)
' If Choice = -1 or "sheets" return True if the order of the Workbook's sheets are protected
' If Choice = -2 or "windows" return True if the Workbook's windows are protected
'
' Feb 2019 by J. Woolley
'
Application.Volatile
If Target Is Nothing Then Set Target = Application.ThisCell
If Not IsNumeric(Choice) Then Choice = LCase(Choice)
Select Case Choice
Case 3, "scenarios": IsProtected = Target.Parent.ProtectScenarios
Case 2, "interface": IsProtected = Target.Parent.ProtectionMode
Case 1, "shapes": IsProtected = Target.Parent.ProtectDrawingObjects
Case 0, "contents": IsProtected = Target.Parent.ProtectContents
Case -1, "sheets": IsProtected = Target.Parent.Parent.ProtectStructure
Case -2, "windows": IsProtected = Target.Parent.Parent.ProtectWindows
Case Else: IsProtected = CVErr(xlErrValue) ' #VALUE! (Error 2015)
End Select

End Function


This Site

Got a version of Excel that uses the ribbon interface (Excel 2007 or later)? This site is for you! If you use an earlier version of Excel, visit our ExcelTips site focusing on the menu interface.

Newest Tips
Subscribe

FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."

(Your e-mail address is not shared with anyone, ever.)

View the most recent newsletter.