Written by Allen Wyatt (last updated May 27, 2023)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, 2021, and Excel in Microsoft 365
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, 2021, and Excel in Microsoft 365.
Dive Deep into Macros! Make Excel do things you thought were impossible, discover techniques you won't find anywhere else, and create powerful automated reports. Bill Jelen and Tracy Syrstad help you instantly visualize information to make it actionable. You’ll find step-by-step instructions, real-world case studies, and 50 workbooks packed with examples and solutions. Check out Microsoft Excel 2019 VBA and Macros today!
Need to modify how a cell reference, in a formula, is constructed? The shortcut described in this tip will help you step ...
Discover MoreBy default, Excel provides some feedback on your formulas so that you can easily locate potential errors. If you get ...
Discover MoreAs the limits on what you can store in Excel have increased, so has the need to consider how to make your workbooks and ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
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
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 © 2025 Sharon Parq Associates, Inc.
Comments