Send Outlook Email With Attachment From Excel
Sending an Outlook Email from Excel is fairly straightforward. The key issue is to make sure that the Outlook library is included in the Excel application. From the VBE, select Tools, then References, and make sure the Microsoft Outlook Library is checked. The code listed below illustrates the relatively small code requirements to send an Email from Excel.
An example of the references section is as follows:
Program Code
Option Explicit Option Base 1 ' **************************************************************** ' This Demonstrates Sending an Email with an Attachment From Excel ' The Developer Must Include the Outlook Library using Tools, ' References ' **************************************************************** Dim strMailToEmailAddress As String Dim strCCEmail As String Dim strSubject As String Dim strBody As String Dim strAttachmentPath As String ' **************************************************************** ' Initialize Variables To Send an Email ' **************************************************************** Sub TestEmailSentFromExcelWithAttachment() strMailToEmailAddress = "CommunityNews@aol.com" strCCEmail = "UserSupport@comcast.net; TechSupport@live.com" strSubject = "Test Of Sending An Email From Excel" strBody = "This is line 1 of the message" & vbCrLf & _ "This is line 2 of the message" & vbCrLf & _ "This is line 3 of the message" strAttachmentPath = "C:\TempRich1\KCHArecommends.pdf" ' **************************************************************** ' Send the Email with Outlook Already Open ' **************************************************************** Call SendEmailWithAttachment End Sub Sub SendEmailWithAttachment() Dim OutApp As Object Dim OutMail As Object ' **************************************************************** ' Create The Outlook Mail Object ' **************************************************************** Set OutApp = CreateObject("Outlook.Application") OutApp.Session.Logon Set OutMail = OutApp.CreateItem(0) ' **************************************************************** ' Display The Email And Let The User Actually Approve It ' And Then The User Will Click the Send Button ' **************************************************************** On Error Resume Next With OutMail .To = strMailToEmailAddress .CC = strCCEmail .BCC = "" .Subject = strSubject .Body = strBody .Attachments.Add strAttachmentPath .Display End With On Error GoTo 0 End Sub
Program Code For Working Example A
The following example sends an email with attachment to all the addresses in Column A.
Option Explicit Public Sub SendEmailWithAttachment() ' **************************************************************** ' Define Variables ' **************************************************************** Dim wkbRecipientList As Workbook Dim wksRecipientList As Worksheet Dim lngNumberOfRowsInRecipients As Long Dim strPathToAttachment As String Dim i As Long ' **************************************************************** ' Set Workbook and Worksheet Variables ' **************************************************************** Set wkbRecipientList = ActiveWorkbook Set wksRecipientList = ActiveWorkbook.ActiveSheet ' **************************************************************** ' Set the Path To The Attachment (Replace This With Your Path) ' **************************************************************** strPathToAttachment = "C:\TestArea\TestData.txt" ' **************************************************************** ' Determine How Many Rows Are In the Worksheet in Column A ' **************************************************************** lngNumberOfRowsInRecipients = wksRecipientList.Cells(Rows.Count, "A").End(xlUp).Row ' **************************************************************** ' Row 1 Is Headers, Row 2 Starts The Data ' **************************************************************** For i = 2 To lngNumberOfRowsInRecipients ' **************************************************************** ' Send An Email Message With Attachment ' And Check To See That It Is Successful ' If Successful, Bold the Font Of The Email Address ' **************************************************************** If SendAnOutlookEmail(wksRecipientList, i, strPathToAttachment) Then wksRecipientList.Cells(i, 1).Font.Bold = True End If Next i End Sub Private Function SendAnOutlookEmail(WorkSheetSource As Worksheet, RowNumber As Long, AttachmentFile As String) As Boolean Dim strMailToEmailAddress As String Dim strSubject As String Dim strBody As String Dim OutApp As Object Dim OutMail As Object SendAnOutlookEmail = False strMailToEmailAddress = WorkSheetSource.Cells(RowNumber, 1) strSubject = "Please See Attachment" strBody = "Your File Has Been Attached To This Email" ' **************************************************************** ' Create The Outlook Mail Object ' **************************************************************** Set OutApp = CreateObject("Outlook.Application") OutApp.Session.Logon Set OutMail = OutApp.CreateItem(0) ' **************************************************************** ' Send The Email ' **************************************************************** On Error GoTo ErrorOccurred With OutMail .To = strMailToEmailAddress .Subject = strSubject .Body = strBody .Attachments.Add AttachmentFile .Send End With ' **************************************************************** ' Mail Was Successful ' **************************************************************** SendAnOutlookEmail = True Continue: On Error GoTo 0 Set OutMail = Nothing Set OutApp = Nothing Exit Function ' **************************************************************** ' Mail Was Not Successful ' **************************************************************** ErrorOccurred: Resume Continue End Function
Program Code For Working Example B
The following example scans a worksheet for reminder notices that are due, and if eligible, sends an email and updates the "date sent" to Today's Date.
Option Explicit ' **************************************************************** ' The Following Was Tested in Excel 2010 and Outlook 2010 ' The VBE, Tools, References included Microsoft Outlook 14.0 ' Object Library ' **************************************************************** Public Sub SendReminderNotices() ' **************************************************************** ' Define Variables ' **************************************************************** Dim wkbReminderList As Workbook Dim wksReminderList As Worksheet Dim lngNumberOfRowsInReminders As Long Dim i As Long ' **************************************************************** ' Set Workbook and Worksheet Variables ' **************************************************************** Set wkbReminderList = ActiveWorkbook Set wksReminderList = ActiveWorkbook.ActiveSheet ' **************************************************************** ' Determine How Many Rows Are In the Worksheet ' **************************************************************** lngNumberOfRowsInReminders = wksReminderList.Cells(Rows.Count, "A").End(xlUp).Row ' **************************************************************** ' For Any Items That Don't Have A Date In Columns 7 or 8, ' Check To See If The Reminder Is Due. ' ' If Reminder Is Due, then Send An Email. ' If Successful, Log The Date Sent in Column 7 or 8 ' **************************************************************** For i = 2 To lngNumberOfRowsInReminders ' **************************************************************** ' First Reminder Date Check ' **************************************************************** If wksReminderList.Cells(i, 7) = "" Then If wksReminderList.Cells(i, 3) <= Date Then If SendAnOutlookEmail(wksReminderList, i) Then wksReminderList.Cells(i, 7) = Date 'Indicate That Reminder1 Was Successful End If End If Else ' **************************************************************** ' Second Reminder Date Check ' **************************************************************** If wksReminderList.Cells(i, 8) = "" Then If wksReminderList.Cells(i, 4) <= Date Then If SendAnOutlookEmail(wksReminderList, i) Then wksReminderList.Cells(i, 8) = Date 'Indicate That Reminder2 Was Successful End If End If End If End If Next i End Sub Private Function SendAnOutlookEmail(WorkSheetSource As Worksheet, RowNumber As Long) As Boolean Dim strMailToEmailAddress As String Dim strSubject As String Dim strBody As String Dim OutApp As Object Dim OutMail As Object SendAnOutlookEmail = False strMailToEmailAddress = WorkSheetSource.Cells(RowNumber, 6) strSubject = "Reminder Notification" strBody = "Line 1 of Reminder" & vbCrLf & _ "Line 2 of Reminder" & vbCrLf & _ "Line 3 of Reminder" ' **************************************************************** ' Create The Outlook Mail Object ' **************************************************************** Set OutApp = CreateObject("Outlook.Application") OutApp.Session.Logon "Outlook" Set OutMail = OutApp.CreateItem(0) ' **************************************************************** ' Send The Email ' **************************************************************** On Error GoTo ErrorOccurred With OutMail .To = strMailToEmailAddress .Subject = strSubject .Body = strBody .Send End With ' **************************************************************** ' Mail Was Successful ' **************************************************************** SendAnOutlookEmail = True Continue: On Error GoTo 0 Set OutMail = Nothing Set OutApp = Nothing Exit Function ' **************************************************************** ' Mail Was Not Successful ' **************************************************************** ErrorOccurred: Resume Continue End Function