March 21, 2021
I have a VBA to send each worksheet as pdf separately but I would now like to have it sent as xls
Sub EmailScript()
Dim ws as Worsheets
Dim wb as Workbook
Dim EmailSubject As String, EmailSignature As String
Dim CurrentMonth As String, DestFolder As String, PDFFile As String
Dim Email_To As String, Email_CC As String, Email_BCC As String
Dim OpenPDFAfterCreating As Boolean, AlwaysOverwritePDF As Boolean, DisplayEmail As Boolean
Dim OverwritePDF As VbMsgBoxResult
Dim OutlookApp As Object, OutlookMail As Object
CurrentMonth = ""
EmailSubject = " - Statement - "
OpenPDFAfterCreating = False
AlwaysOverwritePDF = False
DisplayEmail = True
Email_To = ActiveSheet.Range("E8")
Email_CC = ""
Email_BCC = ""
DestFolder = "C:\Users\arzurc\Documents\Statements"
'Current month/year stored in H6 (this is a merged cell)
CurrentMonth = ActiveSheet.Range("H1").Value
'Create new PDF file name including path and file extension
PDFFile = DestFolder & Application.PathSeparator & ActiveSheet.Name & "_" & CurrentMonth & ".pdf"
'Tried to replace the above with ExcelFile = DestFolder & Application.PathSeparator & ActiveSheet.Name & "_" & CurrentMonth & ".xls"
'Create the PDF
ActiveSheet.ExportAsFixedFormat Type:=xlTypePDF, Filename:=PDFFile, Quality:=xlQualityStandard, IncludeDocProperties:=True, IgnorePrintAreas _
:=False, OpenAfterPublish:=OpenPDFAfterCreating
'Create an Outlook object and new mail message
Set OutlookApp = CreateObject("Outlook.Application")
Set OutlookMail = OutlookApp.CreateItem(0)
'Display email and specify To, Subject, etc
With OutlookMail
.Display
.To = Email_To
.CC = Email_CC
.BCC = Email_BCC
.Subject = ActiveSheet.Name & EmailSubject & CurrentMonth
.Attachments.Add PDFFile '(tried to replace PDFFILE with EXCELFILE)
.Body = "Dear Customer," & vbNewLine & vbNewLine & "Please find attached your latest statement." & vbNewLine & vbNewLine & "Kindest Regards"
If DisplayEmail = True Then
.Send
End If
End With
End Sub
Sub SendAllSheets()
Dim ws As Worksheet
For Each ws In ThisWorkbook.Worksheets
ws.Activate
EmailScript
Next
End Sub
-----------------------------
I tried to add
'Create the Ws
Set wb = ws.Application.Workbooks.Add
ws.Copy Before:=wb.Sheets(5)
wb.SaveAs Path & ws.Name, Excel.XlFileFormat.xlOpenXMLWorkbook
Set wb = Nothing
but it is not attaching the excel file.
Trusted Members
Moderators
November 1, 2018
I would pass the worksheet as an argument to the email routine:
Sub EmailScript(ws As Worksheet)
Dim EmailSubject As String, EmailSignature As String
Dim CurrentMonth As String, DestFolder As String, ExcelFile As String
Dim Email_To As String, Email_CC As String, Email_BCC As String
Dim DisplayEmail As Boolean
Dim OutlookApp As Object, OutlookMail As Object
CurrentMonth = ""
EmailSubject = " - Statement - "
DisplayEmail = True
Email_To = ws.Range("E8")
Email_CC = ""
Email_BCC = ""
DestFolder = "C:\Users\arzurc\Documents\Statements"
'Current month/year stored in H6 (this is a merged cell)
CurrentMonth = ws.Range("H1").Value
'Create new PDF file name including path and file extension
ExcelFile = DestFolder & Application.PathSeparator & ws.Name & "_" & CurrentMonth & ".xls"
'Create the xls file
ws.Copy
ActiveWorkbook.SaveAs Filename:=ExcelFile, FileFormat:=xlExcel8
ActiveWorkbook.Close False
'Create an Outlook object and new mail message
Set OutlookApp = CreateObject("Outlook.Application")
Set OutlookMail = OutlookApp.CreateItem(0)
'Display email and specify To, Subject, etc
With OutlookMail
.Display
.To = Email_To
.CC = Email_CC
.BCC = Email_BCC
.Subject = ws.Name & EmailSubject & CurrentMonth
.Attachments.Add ExcelFile
.Body = "Dear Customer," & vbNewLine & vbNewLine & "Please find attached your latest statement." & vbNewLine & vbNewLine & "Kindest Regards"
If DisplayEmail = True Then
.Send
End If
End With
End Sub
Sub SendAllSheets()
Dim ws As Worksheet
For Each ws In ThisWorkbook.Worksheets
EmailScript ws
Next
End Sub
1 Guest(s)