This post may contain affiliate links. Please read my disclosure for more info:

Automatic e-mail template for Excel

Bulk email template

Automatic e-mail template for Excel

If you speak to anybody who works in the accountancy field, they will always be talking about the “month end”.  In all medium and large companies there will be a process at each month end which requires statements to be issued and reports to be distributed.  This monthly process fills most finance people with a sense of dread.  As simple as it sounds, the process is never smooth and often requires working a lot of additional hours. Wouldn’t it be great if there were a tool which could automate some of the report/statement distribution?  Hmm . . . I wonder.

 

Introducing the Automatic E-mail Template

The Automatic E-mail Template will take away some of the month end pain, it will enable you to set-up a process to automatically send e-mails and documents to many recipients.

Please note, this template will only work where Outlook is being used as the e-mail software.

 

Download the template

The template is available for newsletter subscribers to download for free.

You must thoroughly test this template first as you could easily send hundreds of e-mails by mistake to people who shouldn’t be receiving them.  If you decide to use this template you do so entirely are your own risk.

Please note, you do not need to download the file to create your own E-mail Template, all the instructions and VBA code are in the sections below.

Existing newsletter subscribers can enter their name and e-mail address into the form below for instant access to the download.  Or, you can enter your name and e-mail address below to become a subscriber.







 

How does the template work?

This tool is very simple to use.

Bulk e-mail template

Options:
The e-mail options on the worksheet are:

  • To: e-mail addresses separated by a semicolon
  • CC: e-mail addresses separated by a semicolon
  • BCC: e-mail addresses separated by a semicolon
  • Subject: text string to be used as the subject name
  • Message: text string to be used in the message
  • Attachments: full file paths of the files to be used as attachments, separated by the attachment separator
  • Attachment separator: the character or characters used to separate the list of attachments
  • Send / Display / Save: The option to leave the e-mail displayed, to save and close or to automatically send the e-mail.

Hopefully these options are all reasonably straightforward.

Add new lines:
To add a new line can copy and paste one of the lines from above, then change the settings.

Click Run:
Once the list is ready,  click ‘Run’.  The process will start at the top and keep working down the list until it reaches a blank cell in Column B.

 

Error messages

There are limited error messages included within the code.  Column A will display a tick or cross to identify the rows caused an error.

 

View the code

This file is not locked or protected in any way.  Feel free to view the VBA code and make any changes you wish.

This template comes with no guarantees or warranties what so ever, use it at your own risk.

 

Build your own Automatic E-mail Template

To build your own template from scratch follow the instructions below:

 

Build the worksheet

Set up a worksheet similar to the image below.

Bulk e-mail template

The VBA code has been created to work with the list of e-mail starting at row 6 and with the columns in the exact order shown.

 

VBA Code

Copy the code below into a standard Module.

Sub SendMail()

Dim outApp As Object
Dim i As Long

'Check if Outlook is open
On Error Resume Next
Set outApp = GetObject(, "Outlook.Application")
On Error GoTo 0

If outApp Is Nothing Then
    MsgBox "Outlook is not open. Open Outlook and try again.", vbExclamation
    Exit Sub
End If

'Clear the ticks from column A
Columns("A:A").ClearContents

'The row in which the list of e-mails start
i = 6

While Cells(i, 2).Value <> ""
    updateMail Cells(i, 2), Cells(i, 3), Cells(i, 4), Cells(i, 5), _
        Cells(i, 6), Cells(i, 7), Cells(i, 8), Cells(i, 9), i
    i = i + 1
Wend

Set outApp = Nothing

End Sub
Sub updateMail(ToBox As String, CcBox As String, BccBox As String, _
Subject As String, Message As String, AttachmentList As String, _
AttachmentSeparator As String, Action As String, row As Long)

Dim outApp As Object
Dim outMailItem As Object
Dim i As Integer
Dim attachmentArray() As String

Set outApp = GetObject(, "Outlook.Application")
Set outMailItem = outApp.CreateItem(0)
attachmentArray() = Split(AttachmentList, AttachmentSeparator)

On Error GoTo ErrorFound

'The To, CC and BCC values can send e-mails to multiple recpients
'just ensure the e-mail addresses are separated with a semicolon (;)
With outMailItem
    .To = ToBox
    .CC = CcBox
    .BCC = BccBox
    .Subject = Subject
    .Body = Message

    For i = LBound(attachmentArray) To UBound(attachmentArray)
        .Attachments.Add Trim(attachmentArray(i))
    Next

    Select Case Action

        Case "Display"
            .Display
        Case "Save"
            .Close False
        Case "Send"
            .Send

    End Select

End With

'Display tick or cross
ErrorFound:
If Err.Number = 0 Then
    Cells(row, 1) = "ü"
Else
    Cells(row, 1) = "û"
End If

CleanUp:
Set outMailItem = Nothing
Set outApp = Nothing

End Sub

 

Make month end just a little easier

So, there you have it, the Automatic E-mail Template.  A simple little tool which could save your hours of work every month.  Remember, testing is essential, as it is possible to send a lot of e-mails in error, and nobody wants that!  But once it’s working as you expect, just click the button, then bask in your time-saving glory!







Save

Save

Leave a Reply

Your email address will not be published. Required fields are marked *