Please Note: This article is written for users of the following Microsoft Excel versions: 2007, 2010, 2013, 2016, 2019, Excel in Microsoft 365, and 2021. If you are using an earlier version (Excel 2003 or earlier), this tip may not work for you. For a version of this tip written specifically for earlier versions of Excel, click here: Copying Comments to Cells.

Copying Comments to Cells

Written by Allen Wyatt (last updated April 15, 2023)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, Excel in Microsoft 365, and 2021


2

Hector has a large worksheet containing approximately 600 rows and 70 columns. Spread throughout these 43,000 cells are about 200 cells with comments. (We're talking here about what Microsoft now confusingly calls "notes," but are traditionally called "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:

If you would like to know how to use the macros described on this page (or on any other page on the ExcelTips sites), I've prepared a special page that includes helpful information. Click here to open that special page in a new browser tab.

ExcelTips is your source for cost-effective Microsoft Excel training. This tip (11837) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, Excel in Microsoft 365, and 2021. You can find a version of this tip for the older menu interface of Excel here: Copying Comments to Cells.

Author Bio

Allen Wyatt

With more than 50 non-fiction books and numerous magazine articles to his credit, Allen Wyatt is an internationally recognized author. He is president of Sharon Parq Associates, a computer and publishing services company. ...

MORE FROM ALLEN

Fatal Errors in Word

If Word runs into a problem and the program can't continue, that can be distressing. Here are some things you can check ...

Discover More

Printing Documents without Markup

If you have a document with Track Changes turned on, you can accumulate quite a bit of "markup" in it. Here's how you can ...

Discover More

Compiling Misspelled Words from Documents

Word keeps track of the words that may be misspelled in a document. If you are working with a lot of documents, you may ...

Discover More

Save Time and Supercharge Excel! Automate virtually any routine task and save yourself hours, days, maybe even weeks. Then, learn how to make Excel do things you thought were simply impossible! Mastering advanced Excel macros has never been easier. Check out Excel 2010 VBA and Macros today!

More ExcelTips (ribbon)

Editing a Comment Close to Its Cell

Have you ever chosen to edit a comment, only to find that the comment is quite a ways from the cell with which it is ...

Discover More

Printing Formatted Comments

When you print your worksheet, you may want Excel to include your comments or notes as they appear on the screen. Here's ...

Discover More

Locking the Size of Pictures in Comments

Excel allows you to place pictures inside of comments. If you do this, you may have experienced a situation where the ...

Discover More
Subscribe

FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."

View most recent newsletter.

Comments

If you would like to add an image to your comment (not an avatar, but an image to help in making the point of your comment), include the characters [{fig}] (all 7 characters, in the sequence shown) in your comment text. You’ll be prompted to upload your image when you submit the comment. Maximum image size is 6Mpixels. Images larger than 600px wide or 1000px tall will be reduced. Up to three images may be included in a comment. All images are subject to review. Commenting privileges may be curtailed if inappropriate images are posted.

What is three minus 2?

2023-04-15 12:15:05

J. Woolley

For more on this subject, see my three comments dated March 2022 here: https://excelribbon.tips.net/T011232_Filtering_for_Comments.html


2023-04-15 11:50:56

J. Woolley

Here is a more efficient version of the Tip's macro:

Sub CommentsToCells2()
    Dim rCell As Range, rData As Range
    ' Horizontal displacement
    Const iColOffset As Integer = 78
    ' extract comments from selected range
    If TypeName(Selection) <> "Range" Then Exit Sub
    Set rData = Selection.SpecialCells(xlCellTypeComments)
    For Each rCell In rData
        rCell.Offset(, iColOffset).Value = rCell.Comment.Text
        rCell.Comment.Delete
    Next rCell
End Sub

Reminder: Comments can be included when a sheet is printed. See the Sheet tab of the full Page Layout > Page Setup dialog box.
Finally, My Excel Toolbox includes the following dynamic array function:
=ListComments([AllSheets],[Threaded],[SkipHeader])
This function returns one row for each comment with the following columns: Worksheet, Cell, Author, Comment (text). It works with threaded and unthreaded comments. In older versions of Excel you can use ListComments with the SpillArray function described in UseSpillArray.pdf.
See https://sites.google.com/view/MyExcelToolbox/


This Site

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.

Newest Tips
Subscribe

FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."

(Your e-mail address is not shared with anyone, ever.)

View the most recent newsletter.