• Skip to main content
  • Skip to header right navigation
  • Skip to site footer

My Online Training Hub

Learn Dashboards, Excel, Power BI, Power Query, Power Pivot

  • Courses
  • Pricing
    • Free Courses
    • Power BI Course
    • Excel Power Query Course
    • Power Pivot and DAX Course
    • Excel Dashboard Course
    • Excel PivotTable Course – Quick Start
    • Advanced Excel Formulas Course
    • Excel Expert Advanced Excel Training
    • Excel Tables Course
    • Excel, Word, Outlook
    • Financial Modelling Course
    • Excel PivotTable Course
    • Excel for Customer Service Professionals
    • Excel for Operations Management Course
    • Excel for Decision Making Under Uncertainty Course
    • Excel for Finance Course
    • Excel Analysis ToolPak Course
    • Multi-User Pricing
  • Resources
    • Free Downloads
    • Excel Functions Explained
    • Excel Formulas
    • Excel Add-ins
    • IF Function
      • Excel IF Statement Explained
      • Excel IF AND OR Functions
      • IF Formula Builder
    • Time & Dates in Excel
      • Excel Date & Time
      • Calculating Time in Excel
      • Excel Time Calculation Tricks
      • Excel Date and Time Formatting
    • Excel Keyboard Shortcuts
    • Excel Custom Number Format Guide
    • Pivot Tables Guide
    • VLOOKUP Guide
    • ALT Codes
    • Excel VBA & Macros
    • Excel User Forms
    • VBA String Functions
  • Members
    • Login
    • Password Reset
  • Blog
  • Excel Webinars
  • Excel Forum
    • Register as Forum Member

VBA send worksheet separately|VBA & Macros|Excel Forum|My Online Training Hub

You are here: Home / VBA send worksheet separately|VBA & Macros|Excel Forum|My Online Training Hub
Avatar
sp_LogInOut Log In sp_Registration Register
sp_Search Search
Advanced Search|Last Search Results
Search
Forum Scope




Match



Forum Options



Minimum search word length is 3 characters - maximum search word length is 84 characters
sp_Search Search
sp_RankInfo
Lost password?
sp_CrumbsHome HomeExcel ForumVBA & MacrosVBA send worksheet separately
sp_PrintTopic sp_TopicIcon
VBA send worksheet separately
Avatar
chantal arzur
Member
Members
Level 0
Forum Posts: 9
Member Since:
March 21, 2021
sp_UserOfflineSmall Offline
1
April 9, 2021 - 8:50 pm
sp_Permalink sp_Print

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. 

Avatar
Velouria
London or thereabouts
Moderator
Members


Trusted Members

Moderators
Level 4
Forum Posts: 613
Member Since:
November 1, 2018
sp_UserOfflineSmall Offline
2
April 10, 2021 - 12:53 am
sp_Permalink sp_Print

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

sp_Feed
Go to top
Forum Timezone: Australia/Brisbane
Most Users Ever Online: 245
Currently Online: Philip Treacy, Brian Pham
Guest(s) 8
Currently Browsing this Page:
1 Guest(s)
Top Posters:
SunnyKow: 1432
Anders Sehlstedt: 870
Purfleet: 412
Frans Visser: 346
David_Ng: 306
lea cohen: 219
A.Maurizio: 202
Jessica Stewart: 202
Aye Mu: 201
jaryszek: 183
Newest Members:
drsven
Annie Witbrod
wahab tunde
Cong Le Duc
Faisal Bashir
Ivica Cvetkovski
Blaine Cox
Shankar Srinivasan
riyepa fdgf
Hannah Cave
Forum Stats:
Groups: 3
Forums: 24
Topics: 6205
Posts: 27211

 

Member Stats:
Guest Posters: 49
Members: 31880
Moderators: 3
Admins: 4
Administrators: Mynda Treacy, Philip Treacy, Catalin Bombea, FT
Moderators: MOTH Support, Velouria, Riny van Eekelen
© Simple:Press —sp_Information

Sidebar

Blog Categories

  • Excel
  • Excel Charts
  • Excel Dashboard
  • Excel Formulas
  • Excel PivotTables
  • Excel Shortcuts
  • Excel VBA
  • General Tips
  • Online Training
  • Outlook
  • Power Apps
  • Power Automate
  • Power BI
  • Power Pivot
  • Power Query
microsoft mvp logo
trustpilot excellent rating
Secured by Sucuri Badge
MyOnlineTrainingHub on YouTube Mynda Treacy on Linked In Mynda Treacy on Instagram Mynda Treacy on Twitter Mynda Treacy on Pinterest MyOnlineTrainingHub on Facebook
 

Company

  • About My Online Training Hub
  • Disclosure Statement
  • Frequently Asked Questions
  • Guarantee
  • Privacy Policy
  • Terms & Conditions
  • Testimonials
  • Become an Affiliate

Support

  • Contact
  • Forum
  • Helpdesk - For Technical Issues

Copyright © 2023 · My Online Training Hub · All Rights Reserved. Microsoft and the Microsoft Office logo are trademarks or registered trademarks of Microsoft Corporation in the United States and/or other countries. Product names, logos, brands, and other trademarks featured or referred to within this website are the property of their respective trademark holders.