Need to Print Embedded PDFs

kmackie1

New Member
Joined
Jul 30, 2013
Messages
14
Here is my code so far:

Public Sub PrintPDFFiles()​
Const ADOBEPATH As String = "C:\Program Files (x86)\Adobe\Reader 10.0\Reader\AcroRd32.exe"​
Const FILE_PATH As String = "C:\Users\kmackie\Desktop\Sample\Test"​
Const FILE_EXT As String = "PDF"​

Dim fso, fld, file​

Set fso = CreateObject("Scripting.FileSystemObject")​
Set fld = fso.GetFolder(FILE_PATH)​

For Each file In fld.Files​
If UCase(Right(file.Name, 3)) = FILE_EXT Then​
Shell """" & ADOBEPATH & """/n /t """ & file.Path & """"​
End If​
Next​
End Sub

This code works perfectly for what I am trying to do... except for one thing:

I want to open and print PDFs that are already embedded into my worksheet. I can use the code to open the embedded PDF files:


ActiveSheet.Shapes("Object 1").OLEFormat.Activate​

How on earth can I just open these files and print them. I've spent so long trying to figure this out. If you can't tell... I'm a bit of a newbie.

End result:
I want to be able to click a button, have it open the embedded pdf file in Adobe Reader, Print it, Close Adobe Reader.
I will name my first born son to the man that can solve this problem for me!
 
Re: Need to Print Embedded PDFs - PLEASE HELP :(

Hi Saliman and welcome to MrExcel Board!
Your assumption about wrong truncating of PDF with a comment in it has sense - thank you!
Try this improved code:
Rich (BB code):
Option Explicit
#If VBA7 Then
  Private Declare PtrSafe Function OpenClipboard Lib "user32" (ByVal hWnd As LongPtr) As Long
  Private Declare PtrSafe Function CloseClipboard Lib "user32" () As Long
  Private Declare PtrSafe Function GetClipboardData Lib "user32" (ByVal wFormat As Long) As LongPtr
  Private Declare PtrSafe Function GlobalSize Lib "kernel32" (ByVal hMem As LongPtr) As LongPtr
  Private Declare PtrSafe Function GlobalLock Lib "kernel32" (ByVal hMem As LongPtr) As LongPtr
  Private Declare PtrSafe Function GlobalUnlock Lib "kernel32" (ByVal hMem As LongPtr) As Long
  Private Declare PtrSafe Sub CopyMemory Lib "kernel32" Alias "RtlMoveMemory" (Destination As Any, Source As Any, ByVal Length As LongPtr)
  Dim hWnd As LongPtr, Size As LongPtr, Ptr As LongPtr
#Else
  Private Declare Function OpenClipboard Lib "user32" (ByVal hWnd As Long) As Long
  Private Declare Function CloseClipboard Lib "user32" () As Long
  Private Declare Function GetClipboardData Lib "user32" (ByVal wFormat As Long) As Long
  Private Declare Function GlobalSize Lib "kernel32" (ByVal hMem As Long) As Long
  Private Declare Function GlobalLock Lib "kernel32" (ByVal hMem As Long) As Long
  Private Declare Function GlobalUnlock Lib "kernel32" (ByVal hMem As Long) As Long
  Private Declare Sub CopyMemory Lib "kernel32" Alias "RtlMoveMemory" (Destination As Any, Source As Any, ByVal Length As Long)
  Dim hWnd As Long, Size As Long, Ptr As Long
#End If
 
Sub PrintEmbeddedPDFs_03()
' ZVI:2013-08-01 http://www.mrexcel.com/forum/excel-questions/717204-need-print-embedded-pdfs-please-help.html
' ZVI:2014-05-14 Added subrotines for printing sheets and embedded PDFs
' ZVI:2014-06-28 Fixed the incorrect finding of last "%%EOF" in PDF with comments
 
  Dim a() As Byte, b() As Byte, i As Long, j As Long, k As Long, n As Long
  Dim FN As Integer, f As String, p As Variant, obj As OLEObject
 
  p = ActiveWorkbook.Path
 
  ' Check OleObjects presence
  With ActiveSheet.OLEObjects
    If .Count = 0 Then
      MsgBox "Embedded PDF not found", vbExclamation, "Nothing to print"
      Exit Sub
    End If
  End With
 
  On Error GoTo exit_
 
  ' Print all PDFs embedded into the active sheet
  For Each obj In ActiveSheet.OLEObjects
    i = 0:  hWnd = 0: Size = 0: Ptr = 0
    If obj.progID Like "Acro*.Document*" And obj.OLEType = 1 Then
      obj.Copy
      If OpenClipboard(0) Then
        hWnd = GetClipboardData(49156)
        If hWnd Then Size = GlobalSize(hWnd)
        If Size Then Ptr = GlobalLock(hWnd)
        If Ptr Then
          ReDim a(1 To CLng(Size))
          CopyMemory a(1), ByVal Ptr, Size
          Call GlobalUnlock(hWnd)
          i = InStrB(a, StrConv("%PDF", vbFromUnicode))
          If i Then
            ' --> ZVI:2014-06-28
             k = InStrB(i, a, StrConv("%%EOF", vbFromUnicode))
            While k
              j = k - i + 7
              k = InStrB(k + 5, a, StrConv("%%EOF", vbFromUnicode))
            Wend
            ' <--
            ReDim b(1 To j)
            For k = 1 To j
              b(k) = a(i + k - 1)
            Next
            Ptr = 0
          End If
        End If
        Application.CutCopyMode = False
        CloseClipboard
        If i Then
          n = n + 1
          f = p & "\_printed_.pdf"
          If Len(Dir(f)) Then Kill f
          FN = FreeFile
          Open f For Binary As #FN
          Put #FN, , b
          Close #FN
          CreateObject("wscript.shell").Run "AcroRd32.exe /N /T """ & f & """", , True
          Kill f
        End If
      Else
        Application.CutCopyMode = False
      End If
    End If
  Next
 
  ' Inform how many Embedded PDFs were printed
  MsgBox "Amount of the printed PDFs: " & n, vbInformation, "PrintEmbeddedPDFs"
 
exit_:
 
  If Err Then MsgBox Err.Description, vbCritical, "Error #" & Err.Number
 
End Sub
 
Sub PrintSheetsAndThenEmbeddedPdfs()
  PrintSheets
  PrintEmbeddedPdfs
End Sub
 
Sub PrintSheetsAndPdfs()
  Dim sh As Worksheet, obj As OLEObject
  For Each sh In Worksheets
    With sh.UsedRange
      If .Cells.Count > 1 Or Len(.Cells(1)) Then
        sh.PrintOut
      End If
    End With
    For Each obj In sh.OLEObjects
      If obj.progID Like "Acro*.Document*" And obj.OLEType = 1 Then
        sh.Activate
        Call PrintEmbeddedPDFs_03
        Exit For
      End If
    Next
  Next
End Sub
 
 
Sub PrintSheets()
  Dim sh As Worksheet
  For Each sh In Worksheets
    With sh.UsedRange
      If .Cells.Count > 1 Or Len(.Cells(1)) Then
        sh.PrintOut
      End If
    End With
  Next
End Sub
 
Sub PrintEmbeddedPdfs()
  Dim sh As Worksheet, obj As OLEObject
  For Each sh In Worksheets
    For Each obj In sh.OLEObjects
      If obj.progID Like "Acro*.Document*" And obj.OLEType = 1 Then
        sh.Activate
        Call PrintEmbeddedPDFs_03
        Exit For
      End If
    Next
  Next
End Sub
Best Regards,


Dear ZVI

I hope you are well.

This code has been used for a while with Adobe Reader. No changes have been made, though this code have started playing up recently, it struggles to recognise there is a OLE object and often skips the PDFs.

Any ideas why this may be causing a problem?

Kind regards

Saliman
 
Upvote 0

Excel Facts

Round to nearest half hour?
Use =MROUND(A2,"0:30") to round to nearest half hour. Use =CEILING(A2,"0:30") to round to next half hour.
Re: Need to Print Embedded PDFs - PLEASE HELP :(

It seems to be an issue between Windows and Excel, possibly security settings changed as a result of Windows update? It occurs on more than one PC with either Office 2013 or 2010.

It is quite baffling!
 
Last edited:
Upvote 0
Re: Need to Print Embedded PDFs - PLEASE HELP :(

Hi Saliman,

It’s not the problem of the code, the culprit is embedding of ActiveX objects which are not now compatible across to all versions of Excel because of security reasons. Saving workbook in one version of Excel can cause such a problem in another one. Even (auto) updating of Excel can turn the previously working embedded ActiveX to unreliable state. Deleting of any files with EXD extension can help but seems not always.

My suggestion - don’t use anymore ActiveX object like the button embedded into the sheet. Better use Insert - Shape - Rounded Rectangular and assign the macro to it via the right click. This works absolutely stable in all versions of Excel.

Kind Regards,
 
Last edited:
Upvote 0
Re: Need to Print Embedded PDFs - PLEASE HELP :(

Hi ZVI

Does the OLE object relate to ActiveX control? When I embed a PDF into Excel, is this a ActiveX control? This is the only thing in my spreadsheets, there are no other ActiveX controls or form buttons anywhere. (I removed them all to stop the ActiveX messages coming up).

Let me clarify the problem I am currently experiencing:-

I create a new worksheet. I insert a PDF into Sheet 1. And the same for Sheet 2 and Sheet 3.

I then run your code to print all the three PDFs in one go.

This is where it acts randomly every time the code is run. For example, if run, nothing happens. Or it prints PDF from Sheet 2. Or prints PDF from Sheet 1 and Sheet 3.

I hope this makes more sense?

Kind regards

Saliman
 
Upvote 0
Re: Need to Print Embedded PDFs - PLEASE HELP :(

The inserted PDFs have to be OleObjects.
Certainly the OleObjects are not ActiveX objects, but presence of incompatible ActiveX objects in sheets of any open workbooks can harm the code. It was the case of your post #48.
But if there are no embedded ActiveX in open workbooks then it is not that case now.

So my questions are:
1. What is Operative System?
2. What is version of Excel?
3. What happens at double clicking on such a PDF - does it open on Acrobat Reader or not?

To test the behavior please create a new workbook, insert some PDFs into sheets and run this code to test if all OleObjects are actually counted as OLE objects.
Rich (BB code):
Sub Test1()
  Dim sh As Worksheet, obj As OLEObject
  ' Test contents of OleObjects in sheets of active workbook
  For Each sh In Worksheets
    Debug.Print "Sh=" & sh.Name, "OleObjCount=" & sh.OLEObjects.Count, "ShapesCount=" & sh.Shapes.Count
    For Each obj In sh.OLEObjects
      Debug.Print , obj.progID, obj.OLEType
    Next
  Next
End Sub
 
Last edited:
Upvote 0
Re: Need to Print Embedded PDFs - PLEASE HELP :(

Hi ZVI

I should have been more clear in my previous posts - I apologise. Please see my answers below to your queries:-

1. The operating system is Windows 7
2. Excel version is Microsoft Office Home 2010
3. When double clicking the PDF it opens on Adobe Reader without a issue.

I ran your code, your code seems non-responsive, as it runs without letting me know it has done it. I put in Msgbox ("Hello") to double check. Nothing tells me what is happening other than my msgbox coming up. This is on a sheet with a PDF and a sheet with no PDF with the same results.

Kind regards

Saliman
 
Upvote 0
Re: Need to Print Embedded PDFs - PLEASE HELP :(

Output of the code goes to the Immediate window of VBE.
Press Atr-F11 and Ctrl-G to activate that window.
 
Upvote 0
Re: Need to Print Embedded PDFs - PLEASE HELP :(

The output of the code is

Sh=Sheet1 OleObjCount=1 ShapesCount=1
AcroExch.Document.11 1
Sh=Sheet2 OleObjCount=1 ShapesCount=1
AcroExch.Document.11 1
Sh=Sheet3 OleObjCount=1 ShapesCount=1
AcroExch.Document.11
Sh=Sheet4 OleObjCount=0 ShapesCount=0

Thanks ZVI - I have run a fresh copy of your code from my post #51, given that it appears to correctly detect OleObjCount. Sheet 1 to 3 has PDFs, Sheet 4 is empty.

I ran PrintSheetsAndPDFs sub, and it correctly prints each worksheet with no PDF in it, and it stops at each sheet with PDF sheet saying "Number of PDFs printed - 0" to press OK before moving on to next work sheet. Even though a PDF is on that sheet, it is interesting that the message box only appears when a PDF exists in that sheet, but doesn't attempt to print it.
 
Last edited:
Upvote 0
Re: Need to Print Embedded PDFs - PLEASE HELP :(

Could you please test the cope of post #44 ? I'd suggest that one instead of any previous code.
 
Last edited:
Upvote 0
Re: Need to Print Embedded PDFs - PLEASE HELP :(

Hi ZVI

The code in post #44 was never used purely because it frequently points to Adobe Acrobat, which I do not have. I only have Adobe Reader. Please correct me if I have interpreted it incorrectly.

I ran it anyway with a empty worksheet and an embedded PDF, I get the error message "ActiveX component can't create object" with the title "Error #429".
 
Upvote 0

Forum statistics

Threads
1,216,098
Messages
6,128,812
Members
449,468
Latest member
AGreen17

We've detected that you are using an adblocker.

We have a great community of people providing Excel help here, but the hosting costs are enormous. You can help keep this site running by allowing ads on MrExcel.com.
Allow Ads at MrExcel

Which adblocker are you using?

Disable AdBlock

Follow these easy steps to disable AdBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the icon in the browser’s toolbar.
2)Click on the "Pause on this site" option.
Go back

Disable AdBlock Plus

Follow these easy steps to disable AdBlock Plus

1)Click on the icon in the browser’s toolbar.
2)Click on the toggle to disable it for "mrexcel.com".
Go back

Disable uBlock Origin

Follow these easy steps to disable uBlock Origin

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back

Disable uBlock

Follow these easy steps to disable uBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back
Back
Top