Please Note: This article is written for users of the following Microsoft Excel versions: 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365. 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: Setting Print Ranges for Multiple Worksheets.

Setting Print Ranges for Multiple Worksheets

Written by Allen Wyatt (last updated August 10, 2019)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365


1

Martin asked if there is a way to set print ranges for multiple worksheets at the same time. He has a workbook containing a number of worksheets structured exactly the same, and he wants their respective print ranges to be exactly the same.

As Martin has discovered, there is no way to do this directly in Excel. When you select multiple worksheets, select the area you want set as the print area, and then try to set the print area, you quickly discover that the option to do the setting is grayed out, so you cannot select that option.

There are several things you can try, however. One is to start with a new workbook and develop a single worksheet that contains the print area as you would want it on all worksheets. Then, copy the worksheet however many times desired in the workbook. The copied worksheets will have the print area set as it was in the first worksheet.

The other option is to create a macro that will do the print-area setting for you. Consider the following macro, which will set the print area for all the selected worksheets to whatever the print area is on the active worksheet. (When more than one worksheet is selected, the active worksheet is the one that is visible when you run the macro.)

Sub SetPrintAreas1()
    Dim sPrintArea As String
    Dim wks As Worksheet

    sPrintArea = ActiveSheet.PageSetup.PrintArea
    For Each wks In ActiveWindow.SelectedSheets
        wks.PageSetup.PrintArea = sPrintArea
    Next
    Set wks = Nothing
End Sub

If you prefer to have the print area set to some range that you specify, rather than needing to set the print area on the active worksheet first, then you can make one small change to the macro so that it uses a range for the print area:

Sub SetPrintAreas2()
    Dim sPrintArea As String
    Dim wks As Worksheet

    sPrintArea = "A7:E22"
    For Each wks In ActiveWindow.SelectedSheets
        wks.PageSetup.PrintArea = sPrintArea
    Next
    Set wks = Nothing
End Sub

To choose a different print area for your needs, replace the range that is assigned to the sPrintArea variable. If you figure that you may use the macro quite a bit, in a number of different workbooks, or if you figure that you may need to change the print area regularly, you could change the macro so that it prompts the user for a range to use:

Sub SetPrintAreas3()
    Dim sPrintArea As String
    Dim wks As Worksheet

    sPrintArea = InputBox("Enter print area range")
    For Each wks In ActiveWindow.SelectedSheets
        wks.PageSetup.PrintArea = sPrintArea
    Next
    Set wks = Nothing
End Sub

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 (9365) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365. You can find a version of this tip for the older menu interface of Excel here: Setting Print Ranges for Multiple Worksheets.

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

Default Font for Page Numbers

Page numbers are a common addition to documents, and a great aid to readers. If you want to easily format page numbers, ...

Discover More

Underlining Section References Automatically

If you have a document that has some sort of keyword within it (such as "Section") you may want to automatically format ...

Discover More

Changing Text in Text Boxes on a Chart

Macros allow you to make changes to virtually anything you can see in Excel. This tip examines how to make changes (even ...

Discover More

Excel Smarts for Beginners! Featuring the friendly and trusted For Dummies style, this popular guide shows beginners how to get up and running with Excel while also helping more experienced users get comfortable with the newest features. Check out Excel 2013 For Dummies today!

More ExcelTips (ribbon)

Using a Macro to Set a Print Range

Excel allows you to specify a print range that defines what should be printed from a given worksheet. This tip shows how ...

Discover More

Setting the Print Area

Many people, when they print a worksheet, print the entire thing. You don't have to, however. You can specify that Excel ...

Discover More

Clearing the Print Area

Excel allows you to specify which portions of a worksheet should be printed when you send output to your printer. If you ...

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 eight minus 6?

2019-08-10 21:46:01

MW

Selecting and setting the same print ranges on multiple worksheets is a very common task for users of Excel. If you've had to do it even once on a multi-worksheet workbook you know what a pain it is to do, and wonder why Microsoft didn't include a tool to do that (PS: you can't paste the same graphics into multiple worksheets all at once either).

Not to take anything away from Allen Wyatt's always helpful tips and instructions . . .

I suggest checking out a fabulous Excel Addin that has been on the market since 2000 and will not only set those ranges with a couple of clicks with its built in macros and functions, but it will also perform countless other frequently encountered functions: ASAP Utilities

It is a free program for personal use that is very intuitive, well organized and easy to use; and if you are a frequent user of Excel in business it is many times more valuable than its inexpensive license fee.

Seriously.

Check it out here: https://www.asap-utilities.com/


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.