Jyggalag

Active Member
Joined
Mar 8, 2021
Messages
422
Office Version
  1. 365
  2. 2019
Platform
  1. Windows
Hi all,

I currently have this VBA code:

VBA Code:
Option Explicit

Private Const FilePath As String = "S:\COMPANY\FOLDER OF COMPANY\FOLDER 15\TEST FOLDER\Attachments\"
Sub send_email_complete()
    Dim OutApp As Object
    Dim OutMail As Object
    Dim i As Long
    Dim ws As Worksheet
    Dim col As New Collection, itm As Variant
    Dim ToAddress As String, CCAddress As String, EmailSubject As String
   
    '~~> Change this to the relevant worksheet
    '~~> that has the emails (right now Search Export has it)
    Set ws = ThisWorkbook.Sheets("Search Export")

    Set OutApp = CreateObject("Outlook.Application")
    
    Dim BodyText As String
    BodyText = ws.Range("G2") & "<BR>" & "<BR>" & _
         "<b><u>" & ws.Range("G3") & "</b></u>" & " " & _
         ws.Range("G4") & "<BR>" & "<BR>" & _
         ws.Range("G5") & "<BR>" & _
         ws.Range("G6")
         
   Dim AttachmentName As String
   AttachmentName = FilePath & ws.Cells(2, 6).Value2
         
    For i = 2 To ws.Cells(ws.Rows.Count, "A").End(xlUp).Row
      '~~> Constructing addresses and subject
      
      ToAddress = ws.Cells(i, 2).Value2 & ";" & ws.Cells(i, 3).Value2 & ";" & ws.Cells(i, 4).Value2
                  
      CCAddress = ws.Cells(i, 5).Value2
                   
      EmailSubject = ws.Cells(i, 1).Value2
      '~~> This creates a new email (so we can send out multiple emails)
      Set OutMail = OutApp.CreateItem(0)

      With OutMail
         .To = ToAddress
         .CC = CCAddress
         .Subject = EmailSubject
         .HTMLBody = BodyText
         .Attachments.Add AttachmentName
         
         .Display
      
      End With
   Next i

End Sub

Right now, it takes an attachment stored in cell F2 and sends it out to the emails in the other cells.

However, I want my VBA code to:
1) Save the file as a PDF in this folder: R:\PRIVATE\COMPANY\DEPARTMENT\FOLDER 18\TEST\PDF files
2) Send this file out in the email just as before
3) Delete the PDF from the folder: R:\PRIVATE\COMPANY\DEPARTMENT\FOLDER 18\TEST\PDF files

Does anybody know if this is possible? And if so, can you help me change my VBA to make it work?

Any assistance at all would be immensely appreciated!

Thank you :)

Kind regards,
Jyggalag
 

Excel Facts

Whats the difference between CONCAT and CONCATENATE?
The newer CONCAT function can reference a range of cells. =CONCATENATE(A1,A2,A3,A4,A5) becomes =CONCAT(A1:A5)
What kind of file is it?
Hi Rory!

Happy to see you again :)

Right now the file is an Excel macro-enabled workbook. I want to convert it to a PDF, have it send out the file by email and then delete it from the folder after, as mentioned above.

Can you help with this?

Thank you! :)

Kind regards,
Jyggalag
 
Upvote 0
Are we talking about the file that is running the code, or the one in the path currently specified for the attachment?
 
Upvote 0
Are we talking about the file that is running the code, or the one in the path currently specified for the attachment?
The path in the top of the code refers to where the attachments will lie. I then type the name of the attachment in a cell and the code picks it up

The attachment can be altered as long as i type .docs or .xlsx in the cell after entering the file name

This code will be attached to the macro to send out the email, but I want it edited so it can save the current workbook that is open as a PDF and send it out and then delete it after

hope that makes sense? :) otherwise please ask away!
 
Upvote 0
I'm confused. Do you want the attachment that is currently in the code, plus a PDF copy of the workbook with the code in it?

Also, you really don't have to Like every post I make... ;)
 
Upvote 0
I'm confused. Do you want the attachment that is currently in the code, plus a PDF copy of the workbook with the code in it?

Also, you really don't have to Like every post I make... ;)
No worries! :) I enjoy liking tho :D

Apologies for the late response. Essentially, I want to attach the current workbook as a PDF (I will have the workbook located in the file path as well, so the path is fine.

I want the VBA code to be altered, so it will:

1) Convert the open workbook into a PDF and save it with the name "PDF test" in the folder.
2) Send this newly-saved PDF out by email to the email addresses mentioned in the VBA code i gave in my first post here
3) Delete the PDF from the folder after it has been sent out so as to avoid clutter

Please let me know if I need to elaborate further, would be happy to! :)
 
Upvote 0
OK, then I think you want something like this:

VBA Code:
Option Explicit

Private Const FilePath As String = "S:\COMPANY\FOLDER OF COMPANY\FOLDER 15\TEST FOLDER\Attachments\"
Sub send_email_complete()
    Dim OutApp As Object
    Dim OutMail As Object
    Dim i As Long
    Dim ws As Worksheet
    Dim ToAddress As String, CCAddress As String, EmailSubject As String
   
    '~~> Change this to the relevant worksheet
    '~~> that has the emails (right now Search Export has it)
    Set ws = ThisWorkbook.Sheets("Search Export")

    Set OutApp = CreateObject("Outlook.Application")
    
    Dim BodyText As String
    BodyText = ws.Range("G2") & "<BR>" & "<BR>" & _
         "<b><u>" & ws.Range("G3") & "</b></u>" & " " & _
         ws.Range("G4") & "<BR>" & "<BR>" & _
         ws.Range("G5") & "<BR>" & _
         ws.Range("G6")
         
   Dim AttachmentName As String
   AttachmentName = Left$(ThisWorkbook.FullName, InStrRev(ThisWorkbook.FullName, ".")) & "pdf" ' use existing file name and path for PDF
   If Len(Dir(AttachmentName)) <> 0 Then Kill AttachmentName ' delete any existing PDF
   ThisWorkbook.ExportAsFixedFormat Type:=xlTypePDF, Filename:=AttachmentName ' create pdf version
         
    For i = 2 To ws.Cells(ws.Rows.Count, "A").End(xlUp).Row
      '~~> Constructing addresses and subject
      
      ToAddress = ws.Cells(i, 2).Value2 & ";" & ws.Cells(i, 3).Value2 & ";" & ws.Cells(i, 4).Value2
                  
      CCAddress = ws.Cells(i, 5).Value2
                   
      EmailSubject = ws.Cells(i, 1).Value2
      '~~> This creates a new email (so we can send out multiple emails)
      Set OutMail = OutApp.CreateItem(0)

      With OutMail
         .To = ToAddress
         .CC = CCAddress
         .Subject = EmailSubject
         .HTMLBody = BodyText
         .Attachments.Add AttachmentName
         
         .Display
      
      End With
   Next i
   Kill AttachmentName  ' delete the PDF

End Sub
 
Upvote 0

Forum statistics

Threads
1,214,585
Messages
6,120,394
Members
448,957
Latest member
Hat4Life

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