VBA to create emails with an attachment based on path (folder)

Jonnny

New Member
Joined
Dec 19, 2022
Messages
14
Office Version
  1. 365
Platform
  1. Windows
ABCDEF
Row 1To:ccSubjectBody TextPath of Attachment folderAttachment name
Row 2abc@email1.comabc@email1.comtest email 1For your information...C:\Users\ABC\Desktop\SavedFolder\Folder112192022Invoice12.pdf

Hi,
I want to display emails with an attachment from a certain folder. It will be used by multiple users so the path is different and the users must enter their path in row 2, column E.
In the folder, there will be multiple documents with all different name. If users enter the file name in row 2, column F, VBA create an email with the attachment.

Below is the code I currently use.

Code:
Private Sub CommandButton1_Click()

Dim strbody As String
    Dim xStrFile As String
    Dim xFilePath As String
    Dim xFileDlg As FileDialog
    Dim xFileDlgItem As Variant
    Dim xOutApp As Outlook.Application
    Dim xMailOut As Outlook.MailItem
    Application.ScreenUpdating = False

    Set xOutApp = CreateObject("Outlook.Application")
    Set xMailOut = xOutApp.CreateItem(olMailItem)
    Set xFileDlg = Application.FileDialog(msoFileDialogFilePicker)

 If xFileDlg.Show = -1 Then
        With xMailOut
        .To = ""
        .CC = Rows(2).Columns(4).Value
        .BCC = Rows(2).Columns(3).Value
        .Subject = Rows(2).Columns(5).Value
        .Body = Rows(2).Columns(6).Value
        For Each xFileDlgItem In xFileDlg.SelectedItems
                .Attachments.Add xFileDlgItem
            Next xFileDlgItem
            .Display
    End With
    End If
    Set xMailOut = Nothing
    Set xOutApp = Nothing
    Application.ScreenUpdating = True
End Sub
 
See Mail Range/Selection in the body of the mail for info on that.

Instead of using the .Body, you'd use .HTMLBody and need the function provided in the above link. See below.

VBA Code:
Option Explicit

Private Sub CommandButton1_Click()

Dim xOutApp As Object: Set xOutApp = CreateObject("Outlook.Application")
Dim xMailOut As Object: Set xMailOut = xOutApp.CreateItem(olMailItem)

'set range for loop to look through - column F is the Attach? column
Dim ws As Worksheet: Set ws = ThisWorkbook.Sheets("Sheet1")
'Range for Loop
Dim Lrng As Range: Set Lrng = ws.Range("F5:F" & ws.Cells(ws.Rows.Count, 6).End(xlUp).Row)
'Range for HTML body
Dim Hrng As Range: Set Hrng = ws.Range("B4:E" & ws.Cells(ws.Rows.Count, 2).End(xlUp).Row)
Dim c As Range

Application.ScreenUpdating = False

'add path and file to variables
Dim aPath As String: aPath = ws.Cells(3, 3).Value & "\"

With xMailOut
    .To = ""
    .CC = ""
    .BCC = ""
    .Subject = ws.Cells(1, 3).Value
    'Remove the ws.cells(2,3).value if no longer needed. <br> will create line breaks.
    .HTMLBody = ws.Cells(2, 3).Value & "<br> <br>" & RangetoHTML(Hrng)
    'loops through responses in column F to determine if corresponding attachment should be added
    For Each c In Lrng.Cells
        If ws.Cells(c.Row, 6).Value = "YES" Then 'or use "TRUE" if using form checkbox
            .attachments.Add aPath & ws.Cells(c.Row, 5).Value & ".pdf"
        End If
    Next c
    .Display
End With

Set xMailOut = Nothing
Set xOutApp = Nothing

Application.ScreenUpdating = True

End Sub

Function RangetoHTML(rng As Range)
    
    Dim fso As Object
    Dim ts As Object
    Dim TempFile As String
    Dim TempWB As Workbook

    TempFile = Environ$("temp") & "\" & Format(Now, "dd-mm-yy h-mm-ss") & ".htm"

    'Copy the range and create a new workbook to past the data in
    rng.Copy
    Set TempWB = Workbooks.Add(1)
    With TempWB.Sheets(1)
        .Cells(1).PasteSpecial Paste:=8
        .Cells(1).PasteSpecial xlPasteValues, , False, False
        .Cells(1).PasteSpecial xlPasteFormats, , False, False
        .Cells(1).Select
        Application.CutCopyMode = False
        On Error Resume Next
        .DrawingObjects.Visible = True
        .DrawingObjects.Delete
        On Error GoTo 0
    End With

    'Publish the sheet to a htm file
    With TempWB.PublishObjects.Add( _
         SourceType:=xlSourceRange, _
         Filename:=TempFile, _
         Sheet:=TempWB.Sheets(1).Name, _
         Source:=TempWB.Sheets(1).UsedRange.Address, _
         HtmlType:=xlHtmlStatic)
        .Publish (True)
    End With

    'Read all data from the htm file into RangetoHTML
    Set fso = CreateObject("Scripting.FileSystemObject")
    Set ts = fso.GetFile(TempFile).OpenAsTextStream(1, -2)
    RangetoHTML = ts.readall
    ts.Close
    RangetoHTML = Replace(RangetoHTML, "align=center x:publishsource=", _
                          "align=left x:publishsource=")

    'Close TempWB
    TempWB.Close savechanges:=False

    'Delete the htm file we used in this function
    Kill TempFile

    Set ts = Nothing
    Set fso = Nothing
    Set TempWB = Nothing
End Function
 
Upvote 0

Excel Facts

How to calculate loan payments in Excel?
Use the PMT function: =PMT(5%/12,60,-25000) is for a $25,000 loan, 5% annual interest, 60 month loan.

Forum statistics

Threads
1,214,636
Messages
6,120,664
Members
448,976
Latest member
sweeberry

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