Written by Allen Wyatt (last updated February 26, 2021)
This tip applies to Excel 2007, 2010, 2013, and 2016
Hector has a large worksheet containing approximately 600 rows and 70 columns. Spread throughout these 43,000 cells are about 200 cells with comments. Hector wants to extract the comments and place them into cells to the right of the main body of the data table. If a comment, for instance, is attached to cell C43, then he'd like the text from that comment to end up in cell CC43 and the original comment to be deleted.
You might think that you could use Paste Special to perform the task, but that doesn't work. If you copy the original cells and then use Edit | Paste Special | Comments, then only the comments are pasted to the target cells. They are still comments, and not text in cells, which goes against Hector's goal.
The only way to handle this type of extraction is to use a macro. The following, when run on a selection of cells, will extract the comments, move the comment text, and then delete the original comment.
Sub CommentsToCells() Dim rCell As Excel.Range Dim rData As Excel.Range Dim sComment As String ' Horizontal displacement Const iColOffset As Integer = 78 ' extract comments from selected range If TypeName(Selection) = "Range" Then Set rData = Intersect(Selection, ActiveSheet.UsedRange) For Each rCell In rData.Cells On Error Resume Next sComment = rCell.Comment.Text If Len(sComment) > 0 Then rCell.Offset(, iColOffset).Value = sComment rCell.Comment.Delete End If sComment = "" On Error GoTo 0 Next End If End Sub
The macro uses the iColOffset constant to specify how many cells to the right a comment's text should be moved. In this case, the offset (78) is equal to three "alphabets" (26 * 3), so the text of a comment originally in column C will end up in column CC.
Note:
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (11837) 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: Copying Comments to Cells.
Comprehensive VBA Guide Visual Basic for Applications (VBA) is the language used for writing macros in all Office programs. This complete guide shows both professionals and novices how to master VBA in order to customize the entire Office suite for their needs. Check out Mastering VBA for Office 2010 today!
Need to print out comments, but in a way that you control what is included in the printout? Here's a way you can extract ...
Discover MoreAdding comments to the cells in your worksheets can help to document different aspects of that worksheet. Adding a ...
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."
2021-03-02 11:39:23
J. Woolley
You might be interested in the freely available ListComments array function in My Excel Toolbox. It works with threaded and unthreaded Comments/Notes.
See https://sites.google.com/view/MyExcelToolbox/
And did you know Comments can be included when a sheet is printed? See the Sheet tab of the full Page Layout > Page Setup dialog box.
2021-03-01 14:59:00
I understood you published this Copying Comments to Cells a long time ago and fortunately, reprinted it last week. I had posed this problem several years ago, but unfortunately lost contact with your Excel Tips also for several years. What a big surprise to see the elegant and simple solution you just published. I will have the opportunity to apply it in a real case in a couple of weeks. Allen, I do appreciate very much your effort, time and concern for solving our Excel problems. Thank you. Hector.
2019-08-03 18:24:12
Frederick Rothstein
Here is another (shorter) macro that I think will also do what your macro does...
Sub CommentsToCells()
Dim Cell As Range
' Horizontal displacement
Const iColOffset As Integer = 78
' extract comments from selected range
On Error GoTo NoComments
For Each Cell In Selection.SpecialCells(xlComments)
Cell.Offset(, iColOffset).Value = Cell.Comment.Text
Cell.Comment.Delete
Next
NoComments:
End Sub
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