VBA to export to PDF then email....

hollouise

New Member
Joined
Mar 28, 2022
Messages
2
Office Version
  1. 365
Platform
  1. Windows
I have a VBA macro that I use in excel and have used for years and was created by someone no longer with our company. Due some changes, instead of running the macro to have the file emailed out as an excel attachment I need it as PDF. It applies filters to the data first so that way one person only receives their data. Can someone assist me on this macro to have it export to a PDF instead of excel?

VBA Code:
Sub Send_Row_Or_Rows_Attachment_1()
'Working in 2000-2013
'For Tips see: [URL='http://www.rondebruin.nl/win/winmail/Outlook/tips.htm']Excel Automation - Ron de Bruin[/URL]
    Dim OutApp As Object
    Dim OutMail As Object
    Dim rng As Range
    Dim Ash As Worksheet
    Dim Cws As Worksheet
    Dim Rcount As Long
    Dim Rnum As Long
    Dim FilterRange As Range
    Dim FieldNum As Integer
    Dim mailAddress As String
    Dim NewWB As Workbook
    Dim TempFilePath As String
    Dim TempFileName As String
    Dim FileExtStr As String
    Dim FileFormatNum As Long

    On Error GoTo cleanup
    Set OutApp = CreateObject("Outlook.Application")

    With Application
        .EnableEvents = False
        .ScreenUpdating = False
    End With

    'Set filter sheet, you can also use Sheets("MySheet")
    Set Ash = ActiveSheet

    'Set filter range and filter column (column with names)
    Set FilterRange = Ash.Range("A1:AZ" & Ash.Rows.Count)
    FieldNum = 1    'Filter column = A because the filter range start in column A

    'Add a worksheet for the unique list and copy the unique list in A1
    Set Cws = Worksheets.Add
    FilterRange.Columns(FieldNum).AdvancedFilter _
            Action:=xlFilterCopy, _
            CopyToRange:=Cws.Range("A1"), _
            CriteriaRange:="", Unique:=True

    'Count of the unique values + the header cell
    Rcount = Application.WorksheetFunction.CountA(Cws.Columns(1))

    'If there are unique values start the loop
    If Rcount >= 2 Then
        For Rnum = 2 To Rcount

            'Look for the mail address in the MailInfo worksheet
            mailAddress = ""
            On Error Resume Next
            mailAddress = Application.WorksheetFunction. _
                VLookup(Cws.Cells(Rnum, 1).Value, _
                          Worksheets("Mailinfo").Range("A1:B" & _
                                Worksheets("Mailinfo").Rows.Count), 2, False)
            On Error GoTo 0

            If mailAddress <> "" Then

                'Filter the FilterRange on the FieldNum column
                FilterRange.AutoFilter Field:=FieldNum, _
                                       Criteria1:=Cws.Cells(Rnum, 1).Value

                'Copy the visible data in a new workbook
                With Ash.AutoFilter.Range
                    On Error Resume Next
                    Set rng = .SpecialCells(xlCellTypeVisible)
                    On Error GoTo 0
                End With

                Set NewWB = Workbooks.Add(xlWBATWorksheet)

                rng.Copy
                With NewWB.Sheets(1)
                    .Cells(1).PasteSpecial Paste:=8
                    .Cells(1).PasteSpecial Paste:=xlPasteValues
                    .Cells(1).PasteSpecial Paste:=xlPasteFormats
                    .Cells(1).Select
                    Application.CutCopyMode = False
                End With

                'Create a file name
                TempFilePath = Environ$("temp") & "\"
                TempFileName = "Action Needed for your Exceptions" & " " & Format(Now, "dd-mmm-yy")

                If Val(Application.Version) < 12 Then
                    'You use Excel 97-2003
                    FileExtStr = ".xls": FileFormatNum = -4143
                Else
                    'You use Excel 2007-2013
                    FileExtStr = ".xlsx": FileFormatNum = 51
                End If

                'Save, Mail, Close and Delete the file
                Set OutMail = OutApp.CreateItem(0)

                With NewWB
                    .SaveAs TempFilePath & TempFileName _
                          & FileExtStr, FileFormat:=FileFormatNum
                    On Error Resume Next
                    With OutMail
                        .To = mailAddress
                        .Subject = "LP Initiated Counts needed"
                        .Attachments.Add NewWB.FullName
                        .Body = "Attached are exceptions.  Please feel free to contact me with any questions. Thanks."
                        .Send  'Or use Send
                    End With
                    On Error GoTo 0
                    .Close savechanges:=False
                End With

                Set OutMail = Nothing
                Kill TempFilePath & TempFileName & FileExtStr
            End If

            'Close AutoFilter
            Ash.AutoFilterMode = False

        Next Rnum
    End If

cleanup:
    Set OutApp = Nothing
    Application.DisplayAlerts = False
    Cws.Delete
    Application.DisplayAlerts = True

    With Application
        .EnableEvents = True
        .ScreenUpdating = True
    End With
End Sub
 

Excel Facts

Excel Wisdom
Using a mouse in Excel is the work equivalent of wearing a lanyard when you first get to college
Hi and welcome to MrExcel

Replace this part of the code:

VBA Code:
                With NewWB
                  .ExportAsFixedFormat xlTypePDF, TempFilePath & TempFileName & ".pdf", _
                    xlQualityStandard, True, False, OpenAfterPublish:=False
                    On Error Resume Next
                    With OutMail
                        .To = mailAddress
                        .Subject = "LP Initiated Counts needed"
                        .Attachments.Add TempFilePath & TempFileName & ".pdf"
                        .Body = "Attached are exceptions.  Please feel free to contact me with any questions. Thanks."
                        .Send  'Or use Send
                    End With
                    On Error GoTo 0
                    .Close savechanges:=False
                End With
                Set OutMail = Nothing
                Kill TempFilePath & TempFileName & ".pdf"
 
Upvote 0
Solution
I wasn't trying to use VBA for this. There is an option in Excel to print your data to a PDF file.

In playing with this, I found that if I output to "Microsoft Print to PDF", then I got an error, but
when I printed to "Foxit Phantom PDF Printer" it worked fine.

I went back to try it today and it worked to "Microsoft PDF Printer". I'd sent in a comment about it not working, and maybe that had something to do with it. Who knows?
 
Upvote 0
Hi and welcome to MrExcel

Replace this part of the code:

VBA Code:
                With NewWB
                  .ExportAsFixedFormat xlTypePDF, TempFilePath & TempFileName & ".pdf", _
                    xlQualityStandard, True, False, OpenAfterPublish:=False
                    On Error Resume Next
                    With OutMail
                        .To = mailAddress
                        .Subject = "LP Initiated Counts needed"
                        .Attachments.Add TempFilePath & TempFileName & ".pdf"
                        .Body = "Attached are exceptions.  Please feel free to contact me with any questions. Thanks."
                        .Send  'Or use Send
                    End With
                    On Error GoTo 0
                    .Close savechanges:=False
                End With
                Set OutMail = Nothing
                Kill TempFilePath & TempFileName & ".pdf"
This worked perfect, thank you so much!
 
Upvote 0
I'm glad to help you. Thanks for the feedback.
 
Upvote 0

Forum statistics

Threads
1,214,926
Messages
6,122,305
Members
449,079
Latest member
juggernaut24

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