Please Note: This article is written for users of the following Microsoft Excel versions: 97, 2000, 2002, and 2003. If you are using a later version (Excel 2007 or later), this tip may not work for you. For a version of this tip written specifically for later versions of Excel, click here: Printing All or Nothing.

Printing All or Nothing

by Allen Wyatt
(last updated December 17, 2014)

Karen is looking for a way to print an entire workbook, even if a user chooses to print a single worksheet. In other words, she is looking for a way to print either the entire workbook, or nothing at all—there should be no "in between" options.

The only way to handle this is through the use of a macro. VBA allows you to create macros that are initiated when certain events occur. One of the events that can trigger macros is the "print" event. When someone asks to print, or chooses to see a print preview, the BeforePrint event of the Workbook object is triggered. You can create your own macro that executes when the event is triggered.

Private Sub Workbook_BeforePrint(Cancel As Boolean)
    Dim sht As Variant
    Dim bPreview As Boolean
    Dim iResponse As Integer
    On Error GoTo ErrHandler

    iResponse = MsgBox(prompt:="Do you want to Print Preview?", _
        Buttons:=vbYesNoCancel, Title:="Preview?")

    Select Case iResponse
        Case vbYes
            bPreview = True
        Case vbNo
            bPreview = False
        Case Else
            GoTo ExitHandler
    End Select
    Application.EnableEvents = False
    For Each sht In Sheets
        If sht.Visible Then
            sht.PrintOut Preview:=bPreview
        End If
    Next

ExitHandler:
    Application.EnableEvents = True
    Cancel = True
    Exit Sub

ErrHandler:
    MsgBox Err.Description
    Resume ExitHandler
End Sub

Whenever Excel gets ready to print, or whenever print preview is invoked, the BeforePrint event is triggered and this macro runs. The macro first asks the user if he or she wants to do a print preview. A Select Case structure is used to set the bPreview variable based on the answer to the question. The setting of bPreview then controls what happens.

If the user clicked Cancel when asked about previewing, then the macro is exited and the printing is canceled. Otherwise, each worksheet in the workbook is examined to either print or preview. If the worksheet is visible, it is printed, and the Preview property is set equal to bPreview (True means that the worksheet is previewed; False means it is actually printed).

Notice that the macro sets the EnableEvents property to False. This is done so that no other events can trigger while printing or previewing. If EnableEvents is left "on," then every time the PrintOut method is used, the entire BeforePrint event is again triggered—the user would end up in an endless loop if event handling were not turned off.

Also, note that one of the last things to occur before exiting the macro is that the Cancel property is set to True. This is done so that the original print or print preview request that generated the BeforePrint event is cancelled. There is, after all, no need to complete that request, and the macro did all the print handling for the user.

There is one caveat, of course, to using this approach to printing: If macros are not enabled, the handler will not run and the user can print as desired. (Holding Shift while opening the workbook disables macros and the user most times is asked if they want to enable macros.) Other issues of ExcelTips have discussed this fact.

ExcelTips is your source for cost-effective Microsoft Excel training. This tip (3329) applies to Microsoft Excel 97, 2000, 2002, and 2003. You can find a version of this tip for the ribbon interface of Excel (Excel 2007 and later) here: Printing All or Nothing.

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

Specifying a Backup Location

Backup files created by Word are stored in the same folder in which the document is located. If you want them stored in a ...

Discover More

Changing Many Link Locations

Word makes it easy to establish links between documents. If you need to change the locations for a lot of links at once, you ...

Discover More

Finding Unknown Links

There are several things to try when finding unknown links in Excel.

Discover More

Professional Development Guidance! Four world-class developers offer start-to-finish guidance for building powerful, robust, and secure applications with Excel. The authors show how to consistently make the right design decisions and make the most of Excel's powerful features. Check out Professional Excel Development today!

MORE EXCELTIPS (MENU)

Hiding Errors on Printouts

If there are error values in a worksheet, you may not want those error values to appear on a printout. Excel actually allows ...

Discover More

Using Less Paper on Printouts

If a worksheet contains nothing but a bunch of values in column A, you may be loathe to print the worksheet and "waste" a ...

Discover More

Conditional Printing

If you need to make what Excel prints be based upon conditions in a worksheet, you'll love the information in this tip. There ...

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 for this tip:

There are currently no comments for this tip. (Be the first to leave your comment—just use the simple form above!)

This Site

Got a version of Excel that uses the menu interface (Excel 97, Excel 2000, Excel 2002, or Excel 2003)? This site is for you! If you use a later version of Excel, visit our ExcelTips site focusing on the ribbon interface.

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.

Links and Sharing
Share