Pasting Multiple Worksheets into a Word Document

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


2

Bev has a workbook containing five worksheets. She needs to paste the worksheets into a Word document. She wonders if there is a way to paste all five worksheets at once, rather than one at a time.

One way you can approach this is to combine all five of your worksheets into a single "helper" worksheet, and then paste that worksheet into your document. You can certainly do this manually, but if you need to do it often, then a macro is a quicker approach:

Sub ConCatCopy()
    Dim Sheetnum As Integer
    Dim LastRow As Long

    Sheets.Add After:=Sheets(Sheets.Count)
    ActiveSheet.Name = "WordCopy"
    For Sheetnum = 1 To 5
        With Sheets(Sheetnum)
            .Activate
            .UsedRange.Select
            Selection.Copy
        End With
        Sheets("WordCopy").Select
        LastRow = Sheets("WordCopy").UsedRange.Rows.Count
        If LastRow > 1 Then
            LastRow = LastRow + 1
            Range("A" & LastRow).Select
            ActiveSheet.Paste
        End If
    Next Sheetnum
    Sheets("WordCopy").UsedRange.Select
    Selection.Copy
End Sub

The macro adds a new worksheet (the helper worksheet) named WordCopy. It then copies all of the cells from each of the five worksheets and pastes them into the WordCopy worksheet. Finally, everything in the WordCopy worksheet is copied to the Clipboard. You can then switch to your Word document and press Ctrl+V to paste the information. When done, you can return to your workbook and delete the WordCopy worksheet.

Another macro-based approach will still copy the used cells on each worksheet, but it pastes them directly into a Word document, thereby removing the need for a helper worksheet. Here's the code to try out:

Sub PasteAllWorksheets()
    Const MyDoc = "MyDocument.docx"
    Const wdStory = 6
    Const wdPageBreak = 7
    Dim File As String
    Dim WS As Worksheet

    File = ActiveWorkbook.Path & Application.PathSeparator & MyDoc
    With CreateObject("Word.Application")
        .Visible = True
        .Activate
        With .Documents.Open(Filename:=File)
            For Each WS In ActiveWorkbook.Worksheets
                WS.UsedRange.Copy
                With .ActiveWindow.Selection
                    .EndKey Unit:=wdStory
                    .InsertBreak Type:=wdPageBreak
                    .PasteExcelTable LinkedToExcel:=False, _
                      WordFormatting:=True, RTF:=False
                End With
            Next WS
        End With
    End With
    Application.CutCopyMode = False
End Sub

The macro opens an existing document named MyDocument.docx. If your document uses a different name, then change the value defined as the MyDoc constant at the beginning of the macro. The macro also assumes that this document is in the same folder as the workbook from which you are copying.

The content of each worksheet is pasted at the end of the Word document, with a page break before each Excel worksheet that is pasted. The Excel information is pasted as a Word table.

ExcelTips is your source for cost-effective Microsoft Excel training. This tip (13068) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, Excel in Microsoft 365, and 2021.

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

Creating Scenarios

Excel allows you to create different scenarios for the data in your worksheet. These can be saved and managed using the ...

Discover More

Formatting Page Numbers

Need to format the page numbers you added to your document? Word makes it easy, using the same techniques you use to ...

Discover More

Referencing the Last Six Items in a Formula

If you have a list of data in a column, you may want to determine an average of whatever the last few items are in the ...

Discover More

Solve Real Business Problems Master business modeling and analysis techniques with Excel and transform data into bottom-line results. This hands-on, scenario-focused guide shows you how to use the latest Excel tools to integrate data from multiple tables. Check out Microsoft Excel 2013 Data Analysis and Business Modeling today!

More ExcelTips (ribbon)

Grabbing a User's Name from Excel

One of the settings you can make in Excel is to specify a user's name. This name is accessible through macros, and can ...

Discover More

Arranging Workbook Windows

If you find yourself working with a number of different workbooks at the same time, you may want to arrange your desktop ...

Discover More

Single Clicking Enters Edit Mode

Double-click a cell and you should be able to edit the contents of that cell. If single-clicking a cell results in 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 2 + 2?

2023-05-27 19:07:52

J. Woolley

Re. my previous comment, I should have said:
+ Because "WordCopy" is a new worksheet, LastRow is always 1 (never > 1)


2023-05-27 11:21:49

J. Woolley

This Tip's ConCatCopy macro fails:
+ If there are less than 5 worksheets
+ If there is already a sheet named "WordCopy"
+ If one of the first five sheets is a chart sheet, not a worksheet
+ Because the last row of a new worksheet is always 1 (never > 1)
Here is an improved version:

Sub ConCatCopy2()
    Dim shNew As String, shNum As Integer, lastRow As Long
    If Worksheets.Count < 5 Then Exit Sub
    Worksheets.Add After:=Sheets(Sheets.Count)
    shNew = "WordCopy"
    On Error Resume Next
        Do
            Err.Clear
            ActiveSheet.Name = shNew
            If Err Then shNum = shNum + 1: shNew = "WordCopy" & shNum
        Loop Until Err = 0
    On Error GoTo 0
    lastRow = 1
    For shNum = 1 To 5
        Worksheets(shNum).UsedRange.Copy _
            Destination:=Worksheets(shNew).Cells(lastRow, 1)
        lastRow = Worksheets(shNew).UsedRange.Rows.Count + 1
    Next shNum
    Worksheets(shNew).UsedRange.Copy
End Sub


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.