Written by Allen Wyatt (last updated May 17, 2023)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365
Doug notes that Excel allows you to add comments to cells, but only if the worksheet is unprotected. He wonders if there is a way to allow the addition of comments in protected worksheets.
There are a few ways you can tackle this problem. The first is to simply modify how you protect your worksheet. Starting with an unprotected worksheet, follow these steps:
Figure 1. The Protect Sheet dialog box.
Any worksheet user can now add comments to cells. Note that this allows them to add comments to any cells in the worksheet, not just to those cells that you've formatted as unlocked. In addition, users can also modify (add, change, or delete) any other objects in the worksheet, such as drawings and charts.
If you want a more granular approach to dealing with comments in protected worksheets, then you'll need to resort to using a macro. The concept is to have the macro prompt the user for the comment text, unlock the worksheet, insert the comment, and then relock the worksheet.
Public Sub InsertComment() Dim sPassword As String Dim MyComment As String sPassword = "123" Set commentCell = ActiveCell MyComment = InputBox("Enter your comments", "Comments") ActiveSheet.Unprotect Password:=sPassword Range(commentCell.Address).AddComment Range(commentCell.Address).Comment.Text Text:=MyComment ActiveSheet.Protect Password:=sPassword End Sub
Change the value assigned to the sPassword variable; this is required to unlock and relock the worksheet. Since you are storing the password in the macro, you'll also want to make sure that you take steps to protect the macro (put a password on the VBA module) so others cannot see the password. The macro can be assigned to a shortcut key or added to the Quick Access Toolbar.
Note:
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (12928) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365.
Create Custom Apps with VBA! Discover how to extend the capabilities of Office 2013 (Word, Excel, PowerPoint, Outlook, and Access) with VBA programming, using it for writing macros, automating Office applications, and creating custom applications. Check out Mastering VBA for Office 2013 today!
Want your comment boxes to appear someplace other than the right side of a cell? You may be out of luck, and here's why.
Discover MoreWhen formatting comments, you can use a graphic as a background for the comment box. If you later want to move this ...
Discover MoreWant to make your worksheet comments appear a certain way? It's easy to do using techniques you are already familiar with.
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
2022-03-16 09:57:35
J. Woolley
@Ewald Eppink
To remove a Comment, right-click the cell and pick Delete Note. Comments are now called Notes.
2022-03-15 06:57:55
Ewald Eppink
When adding comments to a specific cell and then using the <Esc>-key you get an error.
Do you have a solution for this?
And is it possible removing comments?
2019-11-23 09:35:04
John Mann
I have the Protect/|Unprotect command on my QAT. I use cell locking and sheeet protection extensively to protect myself from inadvertantly editing or adding data where it's not supposed to be. Since I'm only protecting against myself, a password is an unnecessary extra step. I also make frequent use of cell comments (and to make them more obvious I use a different font colour for cells with comments).
A macro stored in my personal workbook, to make it universally available would be nice. However, the macro suggested, if I'm reading it correctly, recquires a password, which I don't want to use. I could probably figure out how to avoid this by recording a macro of locking or unlocking a cell, then reading the code and using that to guide me in modifying the macro above.
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.
FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
Copyright © 2024 Sharon Parq Associates, Inc.
Comments