Results 1 to 8 of 8

Thread: PDF Creator 1.6.0 OLE objects

  1. #1

    Exclamation PDF Creator 1.6.0 OLE objects



    Register for a FREE account, and/
    or Log in to avoid these ads!

    Hi,

    I was wondering if you could help. I have looked to your code for an earlier version of PDF creator. Currently this is for Excel 2010 and the newest version of PDF Creator 1.6.0

    Goal:
    Print an entire workbook in excel as a PDF - to generate an archived report - using button within the spreadsheet.
    It must include all OLE objects inserted in the last sheet (These are Inserted as Word Documents and displayed as icons, and the random picture -.jpg- every now and again)

    I am not a programmer, so the following code may be entirely wrong. Except for what i have used from other posts of course.

    I do hope you can have a look at it and shed some light in a solution.


    Problems:
    - At points PDF creator gets caught in the DO loops.
    - OLE objects are not listed before collection


    The process of sending each sheet and OLE object to the collection list in PDF creator can be done manually, so there must be a way to automate this process. Please help.

    Code:
    'Called from the button click
    Private Sub OLEToPDF()
    
    
    Dim pdfjob As PDFCreator.clsPDFCreator
    Dim sPDFName As String
    Dim sPDFPath As String
    Dim bRestart As Boolean
    
    
    Dim i As Integer
    Dim ObjList As Integer ' Variable ObjList stores a count of all embedded objects.
    
    
    Sheets("OLE OBJECTS SHEET NAME HERE").Select 'On this Worksheet are the OLEObjects
    
    ObjList = Sheets("OLE OBJECTS SHEET NAME HERE").OLEObjects.Count
    
    
    
    
    '/// Change the output file name here! ///
    sPDFName = "A.pdf" <<<< THIS CAN BE THE WORKBOOK NAME - tried ActiveWorkbook.Name
    sPDFPath = ActiveWorkbook.Path & Application.PathSeparator
    
    
    'Check if worksheet is empty and exit if so
    If IsEmpty(ActiveSheet.UsedRange) Then Exit Sub
    
    
    'Activate error handling and turn off screen updates
    On Error GoTo EarlyExit
    Application.ScreenUpdating = False
    Set pdfjob = New PDFCreator.clsPDFCreator
    
    
    'Check if PDFCreator is already running and attempt to kill the process if so
    Do
    bRestart = False
    Set pdfjob = New PDFCreator.clsPDFCreator
    If pdfjob.cStart("/NoProcessingAtStartup") = False Then
    'PDF Creator is already running. Kill the existing process
    Shell "taskkill /f /im PDFCreator.exe", vbHide
    DoEvents
    Set pdfjob = Nothing
    bRestart = True
    End If
    Loop Until bRestart = False
    
    
    'Assign settings for PDF job
    With pdfjob
    .cOption("UseAutosave") = 1
    .cOption("UseAutosaveDirectory") = 1
    .cOption("AutosaveDirectory") = sPDFPath
    .cOption("AutosaveFilename") = sPDFName
    .cOption("AutosaveFormat") = 0 ' 0 = PDF
    .cClearCache
    End With
    
    
    'Delete the PDF if it already exists
    If Dir(sPDFPath & sPDFName) = sPDFName Then Kill (sPDFPath & sPDFName)
    
    
    'Print the document to PDF
    '************ <<<<<<<<< HERE I ATTEMPT TO SEARCH ALL THE OLE OBJECTS IN THE LAST SHEET TO PRINT BEFORE COLLECTION
    ' Increments the counter variable 'i' in a loop.
    For i = 1 To ObjList
    'Selects the shape.
    Sheets("OLE OBJECTS SHEET NAME HERE").OLEObjects(i).Select
    Selection.Verb Verb:=xlPrimary
    
    ' Makes object active.
    Sheets("OLE OBJECTS SHEET NAME HERE").OLEObjects(i).Activate
    Sheets("OLE OBJECTS SHEET NAME HERE").OLEObjects(i).PrintObject = True
    Set WordApp = GetObject(, "Word.Application")
    WordApp.Visible = False
    Word.App.ActivePrinter = "PDFCreator"
    WordApp.ActiveDocument.PrintOut '<<<PRINT PROCESS OLE DOCUMENT, SEND TO PDF COLLECTION
    Next
    WordApp.Quit
    '****************************************
    '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
    
    
    Cleanup:
    'Release objects and terminate PDFCreator
    Set pdfjob = Nothing
    Shell "taskkill /f /im PDFCreator.exe", vbHide
    On Error GoTo 0
    Application.ScreenUpdating = True
    Exit Sub
    
    
    EarlyExit:
    'Inform user of error, and go to cleanup section
    MsgBox "There was an error encountered. PDFCreator has" & vbCrLf & _
    "has been terminated. Please try again.", _
    vbCritical + vbOKOnly, "Error"
    Resume Cleanup
    End Sub

  2. #2
    Administrator Ken Puls's Avatar
    Join Date
    Mar 2011
    Location
    Nanaimo, BC, Canada
    Posts
    2,276
    Articles
    57
    Blog Entries
    14
    Excel Version
    Excel Office 365 Insider
    Just to be clear here...

    You don't need any of the worksheets printed, you just want to print the OLE Objects. Is that correct?

    With regards to those OLE Objects, if they are Word documents, you want to open Word, and then print the contents to the PDF?

    As far as pictures go, what are you expecting in that case?

    Is there any way you could upload a document with a sample (non-confidential data) of what you're dealing with? I've never tried to do what you're doing here, but that's certainly not to say that it shouldn't be possible.
    Ken Puls, FCPA, FCMA, MS MVP

    Learn to Master Your Data at the Power Query Academy (the world's most comprehensive online Power Query training), with my book M is for Data Monkey, or our new Power Query Recipe cards!

    Main Site: http://www.excelguru.ca -||- Blog: http://www.excelguru.ca/blog -||- Forums: http://www.excelguru.ca/forums
    Check out the Excelguru Facebook Fan Page -||- Follow Me on Twitter

    If you've been given VBA code (a macro) for your solution, but don't know where to put it, CLICK HERE.

  3. #3

    Clarification

    Thank you for your reply.

    Ok, the aim is to make a PDF file (a single document) with all the sheets of the workbook plus the documents included in it (the OLE Object, word documents, shown as icons in the workbook).

    The File: A.xlsm
    It contains X# of sheets Click image for larger version. 

Name:	2.jpg 
Views:	13 
Size:	11.8 KB 
ID:	946
    & the last sheet contains a number of Word documents (inserted OLE Objects displayed as icons)Click image for larger version. 

Name:	1.jpg 
Views:	13 
Size:	39.0 KB 
ID:	947



    After my attempts to print the OLE objects, it seems that is the way to go
    -> Open the Word document, print it to PDF (which sends it to the collection point of PDF creator) and then join it with the rest of the items in the collection list, to consolidate the queue.
    Click image for larger version. 

Name:	3.jpg 
Views:	10 
Size:	62.5 KB 
ID:	948Click image for larger version. 

Name:	4.jpg 
Views:	13 
Size:	57.3 KB 
ID:	949

    As for the pictures, i tried attaching them as an icon (opened with paint) but it works better to add them to the Word documents, which is less of a pain.


    As for a file, I have to make one up, but please let me know if the attached pics suffice.

    Cheers

    Quote Originally Posted by Ken Puls View Post
    Just to be clear here...

    You don't need any of the worksheets printed, you just want to print the OLE Objects. Is that correct?

    With regards to those OLE Objects, if they are Word documents, you want to open Word, and then print the contents to the PDF?

    As far as pictures go, what are you expecting in that case?

    Is there any way you could upload a document with a sample (non-confidential data) of what you're dealing with? I've never tried to do what you're doing here, but that's certainly not to say that it shouldn't be possible.

  4. #4
    Administrator Ken Puls's Avatar
    Join Date
    Mar 2011
    Location
    Nanaimo, BC, Canada
    Posts
    2,276
    Articles
    57
    Blog Entries
    14
    Excel Version
    Excel Office 365 Insider
    To be honest, it would be easier for testing purposes if I had a file to work with. Even if the word docs and worksheets only had nonsense in them (or a "This is Excel page 1", "This is Word document 1", etc...)

    I'm going to need it to test anyway, so if you don't mind, it would save me creating it and doing something that is inconsistent with what you're using.
    Ken Puls, FCPA, FCMA, MS MVP

    Learn to Master Your Data at the Power Query Academy (the world's most comprehensive online Power Query training), with my book M is for Data Monkey, or our new Power Query Recipe cards!

    Main Site: http://www.excelguru.ca -||- Blog: http://www.excelguru.ca/blog -||- Forums: http://www.excelguru.ca/forums
    Check out the Excelguru Facebook Fan Page -||- Follow Me on Twitter

    If you've been given VBA code (a macro) for your solution, but don't know where to put it, CLICK HERE.

  5. #5

    Post

    No probs.
    Here you go.

    Cheers.
    Attached Files Attached Files

  6. #6
    Administrator Ken Puls's Avatar
    Join Date
    Mar 2011
    Location
    Nanaimo, BC, Canada
    Posts
    2,276
    Articles
    57
    Blog Entries
    14
    Excel Version
    Excel Office 365 Insider
    Give this a go:

    Code:
    Sub PrintToPDF_Worksheets_And_OLEObjects()
    'Author       : Ken Puls (www.excelguru.ca)
    'Macro Purpose: Print to PDF file using PDFCreator
    '   (Download from http://sourceforge.net/projects/pdfcreator/)
    '   Designed for early bind, set reference to PDFCreator
        Dim pdfjob As PDFCreator.clsPDFCreator
        Dim sPDFName As String
        Dim sPDFPath As String
        Dim sSheetsToPrint As String
        Dim sSheets() As String
        Dim lSheet As Long
        Dim lTtlSheets As Long
        Dim bRestart As Boolean
        Dim lOLECount As Long
        Dim wsOLE As Worksheet
        Dim wordApp As Object
        '/// Change the output file name here! ///
        sPDFName = "Consolidated.pdf"
        sPDFPath = ActiveWorkbook.Path & Application.PathSeparator
        
        '/// Record the sheets you want to print here! ///
        '/// Use sheet names separated by commas only  ///
        sSheetsToPrint = "Cover Page,Items Impacted,Approved,Change List"
        Set wsOLE = Worksheets("Change List")
        
        'Activate error handling and turn off screen updates
        On Error GoTo EarlyExit
        Application.ScreenUpdating = False
        Set pdfjob = New PDFCreator.clsPDFCreator
        'Check if PDFCreator is already running and attempt to kill the process if so
        Do
            bRestart = False
            Set pdfjob = New PDFCreator.clsPDFCreator
            If pdfjob.cStart("/NoProcessingAtStartup") = False Then
                'PDF Creator is already running.  Kill the existing process
                Shell "taskkill /f /im PDFCreator.exe", vbHide
                DoEvents
                Set pdfjob = Nothing
                bRestart = True
            End If
        Loop Until bRestart = False
        'Assign settings for PDF job
        With pdfjob
            .cOption("UseAutosave") = 1
            .cOption("UseAutosaveDirectory") = 1
            .cOption("AutosaveDirectory") = sPDFPath
            .cOption("AutosaveFilename") = sPDFName
            .cOption("AutosaveFormat") = 0    ' 0 = PDF
            .cClearCache
        End With
        
        'Split the sheets into an array
        sSheets() = Split(sSheetsToPrint, ",")
        'Delete the PDF if it already exists
        If Dir(sPDFPath & sPDFName) = sPDFName Then Kill (sPDFPath & sPDFName)
        'Print the document to PDF
        For lSheet = LBound(sSheets) To UBound(sSheets)
            On Error Resume Next 'To deal with chart sheets
            If Not IsEmpty(Application.Sheets(sSheets(lSheet)).UsedRange) Then
                Application.Sheets(sSheets(lSheet)).PrintOut copies:=1, ActivePrinter:="PDFCreator"
                lTtlSheets = lTtlSheets + 1
            End If
            On Error GoTo EarlyExit
        Next lSheet
        'Wait until all print jobs have entered the print queue
        Do Until pdfjob.cCountOfPrintjobs = lTtlSheets
            DoEvents
        Loop
        'Get OLE Objects too
        If wsOLE.OLEObjects.Count > 0 Then
            On Error Resume Next
            Set wordApp = GetObject(, "Word.Application")
            If Err.Number <> 0 Then
                'Could not get instance, so create a new one
                Err.Clear
                On Error GoTo EarlyExit
                Set wordApp = CreateObject("Word.Application")
                With wordApp
                    .Visible = True
                    '.Documents.Add
                End With
            Else
                'Bound to instance, activate error handling
                On Error GoTo EarlyExit
            End If
           wordApp.ActivePrinter = "PDFCreator"
           For lOLECount = 1 To wsOLE.OLEObjects.Count
                wsOLE.OLEObjects(lOLECount).Verb Verb:=xlPrimary
                wordApp.activedocument.PrintOut '<<<PRINT PROCESS OLE DOCUMENT, SEND TO PDF COLLECTION
                wordApp.activedocument.Close 0 'do not save changes
            Next lOLECount
            wordApp.Quit
        End If
        'Wait until all print jobs have entered the print queue
        Do Until pdfjob.cCountOfPrintjobs = lTtlSheets + lOLECount - 1
            DoEvents
        Loop
        'Combine all PDFs into a single file and stop 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
    Cleanup:
        'Release objects and terminate PDFCreator
        Set pdfjob = Nothing
        Set wordApp = Nothing
        Shell "taskkill /f /im PDFCreator.exe", vbHide
        On Error GoTo 0
        Application.ScreenUpdating = True
        Exit Sub
    EarlyExit:
        'Inform user of error, and go to cleanup section
        MsgBox "There was an error encountered.  PDFCreator has" & vbCrLf & _
               "has been terminated.  Please try again.", _
               vbCritical + vbOKOnly, "Error"
        Resume Cleanup
    End Sub
    File with code in place also attached.
    Attached Files Attached Files
    Ken Puls, FCPA, FCMA, MS MVP

    Learn to Master Your Data at the Power Query Academy (the world's most comprehensive online Power Query training), with my book M is for Data Monkey, or our new Power Query Recipe cards!

    Main Site: http://www.excelguru.ca -||- Blog: http://www.excelguru.ca/blog -||- Forums: http://www.excelguru.ca/forums
    Check out the Excelguru Facebook Fan Page -||- Follow Me on Twitter

    If you've been given VBA code (a macro) for your solution, but don't know where to put it, CLICK HERE.

  7. #7
    Excellent.
    Thank you very much for your help.

    It was not finding the reference to PDF creator @ Set pdfjob = New PDFCreator.clsPDFCreator
    Strange as i was sure i had done it.

    It also closes every other word document that is opened at the time of print, but it does the job really well.

    Thanks again.

    p.s. i will bother you again in the future with re-numbering the sheets and keeping the page layouts in the PDF for ease of reading.

    Merry Christmas

  8. #8
    Administrator Ken Puls's Avatar
    Join Date
    Mar 2011
    Location
    Nanaimo, BC, Canada
    Posts
    2,276
    Articles
    57
    Blog Entries
    14
    Excel Version
    Excel Office 365 Insider
    Merry Christmas to you as well. Start a new thread for the new issues so we can tackle just those.

    Cheers!
    Ken Puls, FCPA, FCMA, MS MVP

    Learn to Master Your Data at the Power Query Academy (the world's most comprehensive online Power Query training), with my book M is for Data Monkey, or our new Power Query Recipe cards!

    Main Site: http://www.excelguru.ca -||- Blog: http://www.excelguru.ca/blog -||- Forums: http://www.excelguru.ca/forums
    Check out the Excelguru Facebook Fan Page -||- Follow Me on Twitter

    If you've been given VBA code (a macro) for your solution, but don't know where to put it, CLICK HERE.

Tags for this Thread

Posting Permissions

  • You may not post new threads
  • You may not post replies
  • You may not post attachments
  • You may not edit your posts
  •