Active Member
February 11, 2017
Hi
Beginner here, I have done a little HTML before but this VBA is new to me,
From the comments thread on the very helpful "Create PDF from Excel Worksheet Then Email It With Outlook" by Phillip Tracey.
I have used this code to successfully email daily reports as pdf, but a little tweak I would also like to insert a preview of the attachment in the email body.
As requested by Catalin Bombea I have opened this thread to upload the file in question, any help is greatly appreciated.
Kind Regards
Barry
Power Query
Power Pivot
Xtreme Pivot Tables
Excel for Decision Making
Excel for Finance
Excel Analysis Toolpak
Power BI
Excel
Word
Outlook
Excel Expert
Excel Customer Service
PowerPoint
November 8, 2013
Hi Barry,
In the attachments section, there is a button to Add Files to the upload Queue, this will allow you to browse for a file. After you select a file, press the Start Upload button, that command will actually attach the file. In many forums, the attachment method is the same, with one button for browse and another button to add the file, maybe the name of the buttons are different (instead of Add Files it should say Browse)
Power Query
Power Pivot
Xtreme Pivot Tables
Excel for Decision Making
Excel for Finance
Excel Analysis Toolpak
Power BI
Excel
Word
Outlook
Excel Expert
Excel Customer Service
PowerPoint
November 8, 2013
Hi Barry,
Here is the code you can use to save the used range as an image, then attach the image in email body as a preview:
Sub create_and_email_pdf()
' Create a PDF from the current sheet and email it as an attachment through Outlook
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, Email_Body As String
Dim OpenPDFAfterCreating As Boolean, AlwaysOverwritePDF As Boolean, DisplayEmail As Boolean
Dim OverwritePDF As VbMsgBoxResult
Dim OutlookApp As Object, OutlookMail As Object
CurrentMonth = ""
' *****************************************************
' ***** You Can Change These Variables *********
EmailSubject = "Daily Flight INFO" 'Change this to change the subject of the email. The current month is added to end of subj line
OpenPDFAfterCreating = False 'Change this if you want to open the PDF after creating it : TRUE or FALSE
AlwaysOverwritePDF = True 'Change this if you always want to overwrite a PDF that already exists :TRUE or FALSE
DisplayEmail = True 'Change this if you don't want to display the email before sending. Note, you must have a TO email address specified for this to work
Email_To = "" 'Change this if you want to specify To email e.g. ActiveSheet.Range("H1") to get email from cell H1
Email_CC = ""
Email_BCC = ""
DestFolder = Worksheets("Settings").Range("A4").Value ' NOTE : there's no trailing slash \
' ******************************************************
'Current month/year stored in H6 (this is a merged cell)
'CurrentMonth = Mid(ActiveSheet.Range("H6").Value, InStr(1, ActiveSheet.Range("H6").Value, " ") + 1)
'Create new PDF file name including path and file extension
PDFFile = DestFolder & Application.PathSeparator & "FLT_Board" & ".pdf"
'If the PDF already exists
If Len(Dir(PDFFile)) > 0 Then
If AlwaysOverwritePDF = False Then
OverwritePDF = MsgBox(PDFFile & " already exists." & vbCrLf & vbCrLf & "Do you want to overwrite it?", vbYesNo + vbQuestion, "File Exists")
On Error Resume Next
'If you want to overwrite the file then delete the current one
If OverwritePDF = vbYes Then
Kill PDFFile
Else
MsgBox "OK then, if you don't overwrite the existing PDF, I can't continue." _
& vbCrLf & vbCrLf & "Press OK to exit this macro.", vbCritical, "Exiting Macro"
Exit Sub
End If
Else
On Error Resume Next
Kill PDFFile
End If
If Err.Number <> 0 Then
MsgBox "Unable to delete existing file. Please make sure the file is not open or write protected." _
& vbCrLf & vbCrLf & "Press OK to exit this macro.", vbCritical, "Unable to Delete File"
Exit Sub
End If
End If
'save sheet as image for preview
SaveAsJPG ActiveSheet.UsedRange, "C:\temp\ImageName.jpg"
'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
.Attachments.Add PDFFile
.Attachments.Add "C:\temp\ImageName.jpg"
.display
.To = Email_To
.CC = Email_CC
.BCC = Email_BCC
.Subject = EmailSubject & CurrentMonth
.HTMLBody = Email_Body & "<br>Preview: <br>" & "<IMG src='ImageName.jpg'><br />" & .HTMLBody
If DisplayEmail = False Then
.Send
End If
End With
End Sub
Sub SaveAsJPG(Rng As Range, FName As String)
Dim Cht As ChartObject
Set Cht = ActiveSheet.ChartObjects.Add(1000, 0, Rng.Width, Rng.Height)
Rng.CopyPicture Appearance:=xlPrinter, Format:=xlPicture
Cht.Chart.Paste
Cht.Chart.Export Filename:=FName, Filtername:="JPG"
Cht.Delete
End Sub
I've highlighted in red the most important changes made to your code.
Active Member
February 11, 2017
Catalin
This is brilliant thanks, After working on it I found I cant use the C:/temp directory, I need to use C:/LocalFiles/ instead, as workbook will be used by a few different users. I edited the file path in the code for each sheet and that's working ok now.
The only issue I have now is, the preview file isn't being overwritten with each use?
So I need to go and manually delete the dailypreview.jpg files from the LocalFiles folder before I use the sheet a second time.
Can you advise?
Kind Regards and thanks again,
Barry
Active Member
February 11, 2017
Catalin
One more question,
Due to having a number of different users I need to protect each sheet, for some reason when the sheet is protected I'm presented with an email that only contains a place holder for the preview file. It seems when the sheet is protected it wont allow the chart function to open and save the chart as jpg?
Thanks again Barry
Power Query
Power Pivot
Xtreme Pivot Tables
Excel for Decision Making
Excel for Finance
Excel Analysis Toolpak
Power BI
Excel
Word
Outlook
Excel Expert
Excel Customer Service
PowerPoint
November 8, 2013
You can use C:\Temp, if you create that folder in that location, it does not exist. The system temp folder is in a different location.
The image will be overwritten each time, but you can create a dynamic name with a time stamp to make it unique, if you want.
FName="C:\temp\ImageName" & Format(Now(),"yyyy-mm-dd-hh-mm-ss") & ".jpg"
Use: activesheet.Unprotect Password:="Pass" to unprotect the sheet at the beginning of the code, then protect back when all the changes are made:
activesheet.Protect Password:="Pass"
1 Guest(s)