Written by Allen Wyatt (last updated November 26, 2022)
This tip applies to Excel 97, 2000, 2002, and 2003
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 menu choices available. If the full range of choices is there, then the worksheet and workbook are unprotected. If there are significant parts 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.
Note:
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (3172) applies to Microsoft Excel 97, 2000, 2002, and 2003. You can find a version of this tip for the ribbon interface of Excel (Excel 2007 and later) here: Visually Showing a Protection Status.
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!
If you share a workbook with others in your office, you will probably want to make sure that some of the worksheets don't ...
Discover MoreYou've protected and saved your worksheet with explicit instructions that you be allowed to insert and delete rows. But ...
Discover MoreWhen you protect a worksheet, one of the benefits is that you can limit which cells can be used for data entry. How a ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
There are currently no comments for this tip. (Be the first to leave your comment—just use the simple form above!)
Got a version of Excel that uses the menu interface (Excel 97, Excel 2000, Excel 2002, or Excel 2003)? This site is for you! If you use a later version of Excel, visit our ExcelTips site focusing on the ribbon interface.
FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
Copyright © 2025 Sharon Parq Associates, Inc.
Comments