• Printing Worksheets To A PDF File (Using Late Binding)

    Introduction:
    This article contains code examples to print worksheets to PDF files, using PDFCreator.

    These code examples are built for PDFCreator, an open source PDF writer utility. Unlike Adobe Acrobat and CutePDF, which both require pro versions to create PDF's via code, PDFCreator is completely free! Download PDF Creator from Sourceforge here. Please note that this code will NOT work with Adobe Acrobat.


    It should also be noted that each of the examples in this section use a Late Bind. If you are not familiar with the difference between Early and Late Binding, please read our article on Early vs Late binding.

    Routines Included In This Article:

    • Print a Single Worksheet to a PDF File
    • Print Multiple Worksheets to Multiple PDF Files
    • Print Multiple Worksheets to a Single PDF File
    Versions Tested:
    These routines were tested successfully using PDFCreator 0.9.1, GPLGhostscript.exe download package, on Windows XP Pro (SP2). Excel versions tested include:
    • Excel 2003
    • Excel 2007
    NOTE: Before you "go it alone" with trying to adapt any of these routines, you may want to read this article, which shares some of the idiosyncrasies discovered in the development of the PDFCreator code samples.

    Print a Single Worksheet to a PDF File:
    Code:
    Option Explicit
    Sub PrintToPDF_Late()
    'Author       : Ken Puls (www.excelguru.ca)
    'Macro Purpose: Print to PDF file using PDFCreator
    '   (Download from http://sourceforge.net/projects/pdfcreator/)
    '   Designed for late bind, no references req'd
        Dim pdfjob As Object
        Dim sPDFName As String
        Dim sPDFPath As String
    
        '/// Change the output file name here! ///
        sPDFName = "testPDF.pdf"
        sPDFPath = ActiveWorkbook.Path & Application.PathSeparator
    
        'Check if worksheet is empty and exit if so
        If IsEmpty(ActiveSheet.UsedRange) Then Exit Sub
        Set pdfjob = CreateObject("PDFCreator.clsPDFCreator")
        With pdfjob
            If .cStart("/NoProcessingAtStartup") = False Then
                MsgBox "Can't initialize PDFCreator.", vbCritical + _
                    vbOKOnly, "PrtPDFCreator"
                Exit Sub
            End If
            .cOption("UseAutosave") = 1
            .cOption("UseAutosaveDirectory") = 1
            .cOption("AutosaveDirectory") = sPDFPath
            .cOption("AutosaveFilename") = sPDFName
            .cOption("AutosaveFormat") = 0    ' 0 = PDF
            .cClearCache
        End With
    
        'Print the document to PDF
        ActiveSheet.PrintOut copies:=1, ActivePrinter:="PDFCreator"
    
        'Wait until the print job has entered the print queue
        Do Until pdfjob.cCountOfPrintjobs = 1
            DoEvents
        Loop
        pdfjob.cPrinterStop = False
    
        'Wait until the file shows up before closing PDF Creator
        Do
            DoEvents
        Loop Until Dir(sPDFPath & sPDFName) = sPDFName
    
        pdfjob.cClose
        Set pdfjob = Nothing
    End Sub
    Print Multiple Worksheets to Multiple PDF Files:
    Code:
    Option Explicit
    Sub PrintToPDF_MultiSheet_Late()
    'Author       : Ken Puls (www.excelguru.ca)
    'Macro Purpose: Print to PDF file using PDFCreator
    '   (Download from http://sourceforge.net/projects/pdfcreator/)
    '   Designed for late bind, no references req'd
        Dim pdfjob As Object
        Dim sPDFName As String
        Dim sPDFPath As String
        Dim lSheet As Long
    
        Set pdfjob = CreateObject("PDFCreator.clsPDFCreator")
        sPDFPath = ActiveWorkbook.Path & Application.PathSeparator
        If pdfjob.cStart("/NoProcessingAtStartup") = False Then
            MsgBox "Can't initialize PDFCreator.", vbCritical + _
                vbOKOnly, "PrtPDFCreator"
            Exit Sub
        End If
    
        For lSheet = 1 To ActiveWorkbook.Sheets.Count
            'Check if worksheet is empty and skip if so
            If Not IsEmpty(ActiveSheet.UsedRange) Then
                With pdfjob
                    '/// Change the output file name here! ///
                    sPDFName = "testPDF" & Sheets(lSheet).Name & ".pdf"
                    .cOption("UseAutosave") = 1
                    .cOption("UseAutosaveDirectory") = 1
                    .cOption("AutosaveDirectory") = sPDFPath
                    .cOption("AutosaveFilename") = sPDFName
                    .cOption("AutosaveFormat") = 0    ' 0 = PDF
                    .cClearCache
                End With
        
                'Print the document to PDF
                Worksheets(lSheet).PrintOut copies:=1, ActivePrinter:="PDFCreator"
        
                'Wait until the print job has entered the print queue
                Do Until pdfjob.cCountOfPrintjobs = 1
                    DoEvents
                Loop
                pdfjob.cPrinterStop = False
        
                'Wait until the file shows up before closing PDF Creator
                Do
                    DoEvents
                Loop Until Dir(sPDFPath & sPDFName) = sPDFName
            End If
        Next lSheet
    
        pdfjob.cClose
        Set pdfjob = Nothing
    End Sub
    Print Multiple Worksheets to a Single PDF File
    Code:
    Option Explicit
    Sub PrintToPDF_MultiSheetToOne_Late()
    'Author       : Ken Puls (www.excelguru.ca)
    'Macro Purpose: Print to PDF file using PDFCreator
    '   (Download from http://sourceforge.net/projects/pdfcreator/)
    '   Designed for late bind, no references req'd
        Dim pdfjob As Object
        Dim sPDFName As String
        Dim sPDFPath As String
        Dim lSheet As Long
        Dim lTtlSheets As Long
    
        '/// Change the output file name here!  ///
        sPDFName = "Consolidated.pdf"
        sPDFPath = ActiveWorkbook.Path & Application.PathSeparator
        Set pdfjob = CreateObject("PDFCreator.clsPDFCreator")
    
        'Make sure the PDF printer can start
        If pdfjob.cStart("/NoProcessingAtStartup") = False Then
            MsgBox "Can't initialize PDFCreator.", vbCritical + _
                vbOKOnly, "Error!"
            Exit Sub
        End If
    
        'Set all defaults
        With pdfjob
            .cOption("UseAutosave") = 1
            .cOption("UseAutosaveDirectory") = 1
            .cOption("AutosaveDirectory") = sPDFPath
            .cOption("AutosaveFilename") = sPDFName
            .cOption("AutosaveFormat") = 0    ' 0 = PDF
            .cClearCache
        End With
    
        'Print the document to PDF
        lTtlSheets = Application.Sheets.Count
        For lSheet = 1 To Application.Sheets.Count
            On Error Resume Next 'To deal with chart sheets
            If Not IsEmpty(Application.Sheets(lSheet).UsedRange) Then
                Application.Sheets(lSheet).PrintOut copies:=1, ActivePrinter:="PDFCreator"
            Else
                lTtlSheets = lTtlSheets - 1
            End If
            On Error GoTo 0
        Next lSheet
    
        'Wait until all print jobs have entered the print queue
        Do Until pdfjob.cCountOfPrintjobs = lTtlSheets
            DoEvents
        Loop
    
        'Combine all PDFs into a single file and start the printer
        With pdfjob
            .cCombineAll
            .cPrinterStop = False
        End With
    
        'Wait until the file shows up before closing PDF Creator
        Do
            DoEvents
        Loop Until Dir(sPDFPath & sPDFName) = sPDFName
    
        pdfjob.cClose
        Set pdfjob = Nothing
    End Sub

     

    I'm afraid that you must be logged in to comment or leave a testimonial. I wish it could be otherwise, but I'm trying to keep my site spam free for everyone's benefit. If you don't yet have an account it's completely free to sign up, and a very quick process. Simply click here to Register. Not only can you post a comment here, but it gives you full access to posts questions in our forum as well!

     

    If you already have an account, and just haven't logged in yet, what are you waiting for? Login Now!