XL:Can't Use PrintOut Method When Custom Dialog Box Is VisibleLast reviewed: March 13, 1998Article ID: Q148723 |
The information in this article applies to:
SYMPTOMSIn Microsoft Excel, you cannot use the PrintOut or the PrintPreview method (to print a sheet or to view it in print preview) when a custom (Microsoft Excel version 5.0 or 7.0) dialog box is visible. If you try to use the PrintOut or the PrintPreview method while a custom (Microsoft Excel version 5.0 or 7.0) dialog box is visible, you receive one of the following error messages:
PrintOut Method of Worksheet class Failed -or- Run-time Error '1004': PrintOut Method of Sheets Class Failed CAUSEThis problem occurs because of the way in which Microsoft Visual Basic for Applications code and custom dialog boxes interact with Microsoft Excel. For example, to use the PrintOut method to send a document called "Sheet1" to your printer, you would normally use the follow command:
Worksheets("Sheet1").PrintOutHowever, when a custom (Microsoft Excel version 5.0 or 7.0) dialog box is visible on the screen, you receive one of the error messages mentioned in the "Symptoms" section of this article.
WORKAROUNDSMicrosoft provides programming examples for illustration only, without warranty either expressed or implied, including, but not limited to, the implied warranties of merchantability and/or fitness for a particular purpose. This article assumes that you are familiar with the programming language being demonstrated and the tools used to create and debug procedures. Microsoft support engineers can help explain the functionality of a particular procedure, but they will not modify these examples to provide added functionality or construct procedures to meet your specific needs. If you have limited programming experience, you may want to contact the Microsoft fee-based consulting line at (800) 936-5200. For more information about the support options available from Microsoft, please see the following page on the World Wide Web:
http://www.microsoft.com/support/supportnet/refguide/default.aspTo work around this problem, use any of the following methods.
Method 1 (Excel 97 for Windows and Excel 98 Macintosh Edition Only)Use a UserForm instead of a custom (Microsoft Excel version 5.0 or 7.0) dialog sheet. For example, do the following:
Method 2You can use a method called tunneling to remove the custom (Microsoft Excel version 5.0 or 7.0) dialog box, perform your print action, and then redisplay the dialog box. To use the PrintOut method, you must first hide or dismiss all custom (Microsoft Excel version 5.0 or 7.0) dialog boxes. The following Visual Basic code example uses tunneling to display a custom (Microsoft Excel version 5.0 or 7.0) dialog box, to hide the dialog box before it prints a worksheet, and to then redisplay the dialog box when the print operation is complete. This example assumes that you have a (Microsoft Excel version 5.0 or 7.0) dialog sheet called "Dialog1" (without the quotation marks) and a worksheet called "Sheet1" (without the quotation marks) that are located in the same workbook, and that you have a macro module with the following macro. The dialog sheet must contain two buttons: DoneButton and PrintButton. Before you run the macro, you need to assign the appropriate macros to the DoneButton and the PrintButton. To do this, follow these steps:
To run the following example, position the insertion point in the line that reads "Sub MainMacro()," and then press the F5 key.
'----------------------------------------------------------------------- Option Explicit Public DoneFlag As Integer, PrintFlag As Integer Sub MainMacro() PrintFlag = 0 ' Initialize PrintFlag. DoneFlag = 0 ' Initialize DoneFlag. DialogSheets("Dialog1").Show ' Show it initially. ' While the DoneFlag does not equal 1 (which will only occur if the ' DoneButton is clicked), continue to loop through the Sub procedure. Do If PrintFlag = 1 Then ' If the PrintFlag is set, then Worksheets("Sheet1"). PrintOut ' print Sheet1 and PrintFlag = 0 ' reset the PrintFlag. DialogSheets("Dialog1").Show ' Reshow it only after End If ' having called the procedure Loop Until DoneFlag = 1 ' that hid it. End Sub Sub DoneButton_Click() DoneFlag = 1 ' Set the DoneFlag. DialogSheets("Dialog1").Hide ' Hide the dialog box. End Sub Sub PrintButton_Click() DoneFlag = 0 ' Ensure DoneFlag set to 0. PrintFlag = 1 ' Set the PrintFlag. DialogSheets("Dialog1").Hide ' Hide the dialog box. End Sub '-----------------------------------------------------------------------When you activate the DoneButton or the PrintButton button, the appropriate Sub procedure (DoneButton_Click or PrintButton_Click) runs. Within each Subprocedure, the Dialog1 dialog box is hidden and a flag (DoneFlag or PrintFlag) is set to 1. The MainMacro Sub procedure then resumes and loops back; if PrintFlag equals 1, the macro prints the worksheet and redisplays the dialog box; if DoneFlag equals 1, the macro exits the loop and ends the macro. In this way, the PrintOut method is only executed if the Dialog1 dialog box is not visible on the screen, and the dialog box will reappear until you exit the loop by activating the DoneButton.
Method 3This method provides another way to work around the behavior. Use the OnTime method to allow the macro that contains the DialogSheets("sheetname").Show to complete before you run the PrintOut method. The following sample procedures illustrate this workaround. When you use this code, the print button dismisses the dialog box, and one second later, the print macro runs. One second after the sheet prints, the dialog box appears again. Note the following regarding the sample procedures:
'-------------------------------------------------------------------- Sub ShowTheDialog() ' This portion of the macro could be much larger, ' setting variables and conditions prior to displaying the dialog ' box. ' The last line should be this: DialogSheets("Dialog1").Show End Sub Sub PrintTheSheet() ' This macro should be attached to a button with the Dismiss ' property set and should contain only this line: Application.OnTime Now + TimeValue("00:00:01"), "BackgroundPrint" End Sub Sub BackgroundPrint() ' Like ShowTheDialog, this macro can be much larger, ' selecting areas, defining print ranges, or whatever before ' printing. ActiveSheet.PrintOut ' This line is optional; use it as the last line if you want the ' dialog box to reappear. Application.OnTime Now + TimeValue("00:00:01"), "RedisplayDialog" End Sub Sub RedisplayDialog() ' This optional macro recalls the dialog box without resetting any ' variable, and should contain only this line: DialogSheets("Dialog1").Show End Sub '-------------------------------------------------------------------- Method 4This workaround checks to see if the Print button in the dialog box was clicked. If the button was clicked, the macro prints after the dialog box is dismissed.
REFERENCESFor more information about the PrintOut method, click the Index tab in Microsoft Excel Help, type the following text
printoutand then double-click the selected text to go to the "PrintOut Method" topic. For more information about the PrintPreview method, click the Index tab in Microsoft Excel Help, type the following text
printpreviewand then double-click the selected text to go to the "PrintPreview Method" topic.
|
Additional query words: 5.00 5.00a 5.00c 7.00 8.00 xl97user fail
© 1998 Microsoft Corporation. All rights reserved. Terms of Use. |