Microsoft Excel
Back to jkp-ads.com

Ron de Bruin
Excel Automation

Microsoft MVP Program

Mail a small message

Important message to visitors of this page

Ron de Bruin decided to remove all Windows Excel content from his website for personal reasons. If you want to know why, head over to rondebruin.nl.

Luckily, Ron was kind enough to allow me to publish all of his Excel content here.

Most of these pages are slightly outdated and may contain links that don 't work. Please inform me if you find such an error and I'll try to fix it.

Kind regards

Jan Karel Pieterse


Important read this :

The code on this page is only working when you use Outlook as your mail program.
Copy the code in a Standard module of your workbook, if you just started with VBA see this page.
Where do I paste the code that I find on the internet

Check out this Tip page for changing the code on this page.
Tips for changing the code examples

 

Example 1

The following subroutine sends a small text in an e-mail message.
Change the mail address and subject in the macro before you run it.

Sub Mail_small_Text_Outlook()
'For Tips see: https://jkp-ads.com/rdb/win/winmail/Outlook/tips.htm
'Working in Office 2000-2016
    Dim OutApp As Object
    Dim OutMail As Object
    Dim strbody As String

    Set OutApp = CreateObject("Outlook.Application")
    Set OutMail = OutApp.CreateItem(0)

    strbody = "Hi there" & vbNewLine & vbNewLine & _
              "This is line 1" & vbNewLine & _
              "This is line 2" & vbNewLine & _
              "This is line 3" & vbNewLine & _
              "This is line 4"

    On Error Resume Next
    With OutMail
        .To = "ron@debruin.nl"
        .CC = ""
        .BCC = ""
        .Subject = "This is the Subject line"
        .Body = strbody
        'You can add a file like this
        '.Attachments.Add ("C:\test.txt")
        .Send   'or use .Display
    End With
    On Error GoTo 0

    Set OutMail = Nothing
    Set OutApp = Nothing
End Sub

 

Example 2

The following subroutine sends the text from a txt file in the body of the mail.
Change the mail address, subject and path/name of the txt file in the macro before you run it.
I use C:\test.txt in this example. Note: this example also use the GetBoiler function,
you can find it below the macro. Copy this function also in your standard module.

Sub Mail_Text_From_Txtfile_Outlook()
'For Tips see: https://jkp-ads.com/rdb/win/winmail/Outlook/tips.htm
'Working in Office 2000-2016
    Dim OutApp As Object
    Dim OutMail As Object

    Set OutApp = CreateObject("Outlook.Application")
    Set OutMail = OutApp.CreateItem(0)

    On Error Resume Next
    With OutMail
        .To = "ron@debruin.nl"
        .CC = ""
        .BCC = ""
        .Subject = "This is the Subject line"
        .Body = GetBoiler("C:\test.txt")
        'You can add a file like this
        '.Attachments.Add ("C:\test.txt")
        .Send   'or use .Display
    End With
    On Error GoTo 0

    Set OutMail = Nothing
    Set OutApp = Nothing
End Sub


Function GetBoiler(ByVal sFile As String) As String
'Dick Kusleika
    Dim fso As Object
    Dim ts As Object
    Set fso = CreateObject("Scripting.FileSystemObject")
    Set ts = fso.GetFile(sFile).OpenAsTextStream(1, -2)
    GetBoiler = ts.readall
    ts.Close
End Function

 

Early Binding

If you want to use the Intellisense help showing you the properties and methods of the objects as you type you can use Early Binding. Bit faster also when you run your code but you can have problems when you distribute your workbooks. Excel will automatic update the reference number to Outlook when you open your workbook in a higher version of Excel/Outlook but not update it when you open it in a lower version of Excel/Outlook. With Late Binding as I used in the macro examples you not have this problem.

Add a reference to the Microsoft Outlook Library in Excel

1) Go to the VBA editor with the shortcut Alt - F11
2) Click on Tools>References in the Menu bar
3) Place a Checkmark before Microsoft Outlook ? Object Library
    Where ? is the Outlook version number

Then replace this three lines in the code

Dim OutApp As Object
Dim OutMail As Object

Set OutMail = OutApp.CreateItem(0)


With this three lines

Dim OutApp As Outlook.Application
Dim OutMail As Outlook.MailItem

Set OutMail = OutApp.CreateItem(olMailItem)