Written by Allen Wyatt (last updated January 21, 2022)
This tip applies to Excel 2007, 2010, 2013, and 2016
Robert has a worksheet that has comments included in various places. He wonders if it is possible to filter the rows in a data table so that only those rows that include comments in a particular column are displayed.
The filtering capabilities of Excel don't provide a way that you can automatically check for the presence of comments, but there are a couple of ways you can approach a solution. One possible solution is to follow these general steps:
Figure 1. The Go To dialog box.
Figure 2. The Go To Special dialog box.
If you prefer, you can create a user-defined function that will let you know if a particular cell has a comment associated with it. The following is a simple way to make such a determination:
Function CellHasComment(c As Range) Application.Volatile True CellHasComment = Not c.Comment Is Nothing End Function
Now you can use a formula such as the following within a worksheet:
=CellHasComment(B2)
When the formula is executed, it returns either True or False, depending on whether cell B2 has a comment or not. You can then use Excel's filtering capabilities to display only those rows that have a True returned by the formula.
Note:
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (11232) applies to Microsoft Excel 2007, 2010, 2013, and 2016. You can find a version of this tip for the older menu interface of Excel here: Filtering for Comments.
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!
One way that you can view comments in a worksheet is to have them appear when you hover the mouse pointer over a cell. If ...
Discover MoreComments are a great way to document your worksheets. Excel provides you the tools you need in order to format your ...
Discover MoreNeed to copy whatever is in a comment (a "note") into a cell on your worksheet? If you have lots of comments, manually ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
2022-03-20 12:52:26
J. Woolley
My Excel Toolbox includes the following function returning TRUE if any cell in Target includes a comment:
=HasComment([Target],[Threaded])
Target is the range of cells to consider; default is the formula's cell.
If Threaded is TRUE, only threaded Comments will be considered; default is FALSE for legacy unthreaded comments (Notes). To consider both over columns A:F in row 2:
=OR(HasComment(A2:F2,TRUE),HasComment(A2:F2))
See https://sites.google.com/view/MyExcelToolbox/
2022-03-18 11:22:42
J. Woolley
Re. my previous comment, I forgot about this Define Name weirdness. If you define a Name that refers to a formula using A1 style cell references, it automatically becomes worksheet specific. But using relative R1C1 style cell references avoids this problem. So that part of my previous comment can be modified as follows:
Pick Formulas > Define Name... with
Name: IsComment
Scope: Workbook
Refers to: =NOT(ISERROR(CommentText(INDIRECT("R[0]C[0]",FALSE))))
Then it is possible to define Conditional Formatting for any range on any worksheet of the workbook using =IsComment as the Formula Rule.
2022-03-17 14:07:06
J. Woolley
My Excel Toolbox includes the following function to return the text of a Target cell's comment:
=CommentText(Target,[SkipAuthor])
This function will return the text of either a legacy unthreaded comment (Note) or a threaded Comment. If SkipAuthor is FALSE (default), the comment's author will be included in the returned text if available; otherwise, the comment's author will be removed if possible. If Target is a multi-cell range, its top-left cell applies. If Target's cell does not have a comment, #VALUE! (Error 2015) will be returned.
I use My Excel Toolbox as an add-in; therefore, the CommentText function cannot be referenced in a Conditional Formatting Rule. But there is a work-around. Pick Formulas > Define Name... with
Name: IsComment
Scope: worksheet
Refers to: =NOT(ISERROR(CommentText(A1)))
Then it is possible to define Conditional Formatting for any range on the same worksheet using =IsComment as the Formula Rule. For example, apply a fill color to each cell where the Rule is TRUE. You can filter based on cell color as suggested by Willy Vanhaelen, and each cell's color will update whenever a comment is added or deleted (press Shift+F9 to recalculate). Repeat this work-around for each applicable worksheet.
The procedures described so far only permit filtering for rows that have comments in a single column. To filter for rows that have comments in more than one column, use a helper column with a function suggested by the Tip, but modify that function as follows:
Function CellHasComment(R As Range)
Dim C As Range, B As Boolean
Application.Volatile True
For Each C In R
B = B Or Not C.Comment Is Nothing Or _
Not C.CommentThreaded Is Nothing
Next C
CellHasComment = B
End Function
Assuming cells in columns A:F might have a comment, put this formula in row 2 of the helper column and copy the formula down that column:
=CellHasComment(A2:F2)
Now you can filter for rows that have TRUE in the helper column.
See https://sites.google.com/view/MyExcelToolbox/
2016-09-06 16:57:43
Neil
Great tip, thanks Willy and Allen!
2016-09-04 05:18:48
Willy Vanhaelen
It can be done without a helper column:
1) Select the column that contains comments to be filtered.
2) Follow steps 3) tot 5) of the tip
3) Fill the selected cells with a color of your choice
4) Filter the column by this color
If you dont like the colors to be permanent you can easily remove them after you are done.
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 © 2023 Sharon Parq Associates, Inc.
Comments