Written by Allen Wyatt (last updated August 6, 2024)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365
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.
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!
Want to print your worksheets to their own PDF? This can be quite manually intensive, unless you put the macro in this ...
Discover MoreNeed to print your worksheet on a non-standard paper size? Excel is rather limited in printing to such papers, and here ...
Discover MoreIf you want to automatically print a particular area of your worksheet at a specific time of day, you'll love this tip. ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
2020-09-30 15:29:18
Camilo Ramos
Thanks a lot, good explanation
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 © 2024 Sharon Parq Associates, Inc.
Comments