Written by Allen Wyatt (last updated September 24, 2021)
This tip applies to Excel 2007, 2010, and 2013
Mikki is looking for a way to change the default color on worksheet comments so that she can tell her comments apart from comments made by other people.
When you add a comment to a cell in a worksheet, Excel allows you to change the formatting used for that comment. Once the comment is created, follow these steps:
These steps are all fine and good, but they affect only the current comment. If you want to set a default for any comments you add in the future, Excel doesn't remember your formatting and it provides no way to make a change to the defaults. Instead, Excel grabs its default comment formatting from Windows itself. You can modify this by changing the display properties for Windows, specifically the ToolTip display setting. If you modify this, then you have modified how Excel formats your comments. (You've also modified how ToolTips appear in every other program on your system, as well.)
A workaround is to use a macro to insert your comments. The macro can not only insert the comment, but also format it according to your needs. Here's an example of a short macro that will insert a comment for the selected cell and, if the user's name is "Mikki," make the background color turquoise. (The user's name is defined in the setup for Excel.)
Sub AddMyComment() Dim sUserName As String Dim addr As String sUserName = Application.UserName With ActiveCell addr = .Address If sUserName = "Mikki" Then ActiveSheet.Range(addr).AddComment Range(addr).Comment.Shape.Select True Selection.ShapeRange.Fill.ForeColor.SchemeColor = 41 Else Range(addr).AddComment End If End With End Sub
If you already have a worksheet that contains many comments, you might want to look for comments that have the text "Mikki" within them and then change the color of those comments. This macro fits the bill:
Sub ColorMyComments1() Dim myCom As Comment For Each myCom In ActiveSheet.Comments If InStr(myCom.Text, "Mikki") <> 0 Then myCom.Shape.Fill.ForeColor.SchemeColor = 41 End If Next myCom End Sub
Understand that the macro will change the color if the text "Mikki" appears anywhere within the comment text. A slight variation of the macro checks the comment's Author attribute, and if it is set to "Mikki," then it makes the change:
Sub ColorMyComments2() Dim myCom As Comment For Each myCom In ActiveSheet.Comments If myCom.Author = "Mikki" Then myCom.Shape.Fill.ForeColor.SchemeColor = 41 End If Next myCom End Sub
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (12567) applies to Microsoft Excel 2007, 2010, and 2013.
Program Successfully in Excel! John Walkenbach's name is synonymous with excellence in deciphering complex technical topics. With this comprehensive guide, "Mr. Spreadsheet" shows how to maximize your Excel experience using professional spreadsheet application development tips from his own personal bookshelf. Check out Excel 2013 Power Programming with VBA today!
Excel won't allow you to directly or automatically insert the results of a formula into a cell's comment. You can, ...
Discover MoreComments and notes can be very helpful in a worksheet. After they are added, you may want to change what they contain. ...
Discover MoreExcel allows you to use a picture as a background on a cell comment. This tip looks at how you can paste pictures into a ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
2013-07-09 07:08:53
Frank S
Can you modify this macro to change the default comment font size too?
2013-03-25 09:58:49
Duncan Philps-Tate
With a little bit of modification, you can arrange for a different colour for each author that's found. This needs a loop in the Else statement of the If and an array to hold the authors' names. For simplicity I've started from color 40 and limited the upper end to color 52 once more than 12 authors have been found - this is partly for readability in my own scheme. There is an upper limit on SchemeColor of 80 in any case. Your own author name which appears by default when you create a comment is held as a constant edited into the macro.
Here's the important part of the code:
If myCom.Author = sMyAuthor Then
myCom.Shape.Fill.ForeColor.SchemeColor = 40 'myCom.Shape.Fill.ForeColor.SchemeColor + 1
Else
For i = 0 To UBound(myPeople)
If myPeople(i) = myCom.Author Then
myColor = 41 + i
If myColor > 52 Then myColor = 52
bAuthorExists = True
Exit For
End If
Next 'i
If Not bAuthorExists Then
ReDim Preserve myPeople(UBound(myPeople) + 1)
myPeople(UBound(myPeople)) = myCom.Author
End If
myCom.Shape.Fill.ForeColor.SchemeColor = myColor
End If
2013-03-23 10:28:19
Peter Atherton
I hadn't realised that the Author property applied to comments. I think that that will suit Mikki the best. Congratualtions to the op who supplied that.
Peter
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