Executing a Macro After Printing is Done

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


1

Franklin has a macro that hides some rows in a worksheet and then prints the worksheet. To do this he uses the BeforePrint event handler. The problem is, Franklin wants to unhide the rows automatically after the printing is completed. He doesn't know how to do this within his macro.

There are a few ways you can approach this. One is to use the BeforePrint event handler and use it to hide the rows you want and then to specify a macro to run via the OnTime method. Here's the way the event handler would look:

Private Sub Workbook_BeforePrint(Cancel As Boolean)
    ' Code here to hide rows desired

    Application.OnTime Now, "AfterPrint"
End Sub

You'll need to add to this event handler the code to hide the rows you want hidden. (Franklin said that he had such code working; it was unhiding them after printing that he was having problems with.) Note that the macro being called via OnTime is one called AfterPrint. This macro should be placed within a regular module, not in the same module as the event handlers are placed. It can be even simpler than the event handler:

Sub AfterPrint()
    ' Code here to unhide rows
    Cells.Select
    Selection.EntireRow.Hidden = False
End Sub

You could also, if desired, bypass the need for the OnTime method (and the AfterPrint macro) completely. This would involve this approach:

Private Sub Workbook_BeforePrint(Cancel As Boolean)
    Cancel = True
    ' Code here to hide rows desired

    Application.EnableEvents = False
    ActiveSheet.PrintOut
    Application.EnableEvents = True

    ' Code here to unhide rows
End Sub

The macro works because it cancels the print that triggered the BeforePrint event, hides the rows, prints out the active worksheet, and then unhides the rows.

The drawback to any such event-handler-based approach is that it limits what the user can print. In other words, the user can only print what you allow them to print, not what they may actually want to print. To get around this rather large limitation, you'll need to abandon the BeforePrint approach completely. Instead, create a regular macro that handles the printing:

Sub PrintWS()
    ' Code here to hide rows desired

    Application.EnableEvents = False
    ActiveSheet.PrintOut
    Application.EnableEvents = True

    ' Code here to unhide rows
End Sub

You'll note that this is, essentially, the guts of the second BeforePrint approach—you hide rows, print the worksheet, and then unhide the rows. This PrintWS macro could then be tied to a shortcut key or something on the Quick Access Toolbar so it can be called easily.

By the way, if you decide to go with one of the BeforePrint approaches, there have been reports of it not working properly in all versions of Excel. (This seems very hard to track down.) What happens is that in some versions, what Excel prints is "set in stone" before the BeforePrint event handler is invoked. This means that any rows you hide within the event handler are ignored when the worksheet is actually printed, so it is as if you never hid the rows in the macro. The only way around this very frustrating fact is to handle the printing yourself, directly, either through the second BeforePrint example above or the PrintWS macro approach.

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

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

Copying and Moving Footnotes

Want to get your footnotes from one place to another in a document, or even from one document to another document? It's ...

Discover More

Struggling with New Changes to Track Changes

In the latest versions of Microsoft 365, the company has introduced an entirely new way to deal with markup comments. ...

Discover More

Repeating Rows at the Bottom of a Page

Excel allows you to repeat rows at the top of every page of a printout. If you want to repeat rows at the bottom of every ...

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)

Printing a Range of Pages

If your worksheet, when printed, requires more than a single page to print, you may want to only print a range of the ...

Discover More

Protecting Print Settings

Need to have your print settings always be a certain way? Tired of resetting the settings after others use the workbook ...

Discover More

Using Duplex Printing

Need to print on both sides of a piece of paper? If your printer can handle it, you can duplex your output from within ...

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 six minus 4?

2020-09-30 15:29:18

Camilo Ramos

Thanks a lot, good explanation


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.