Microsoft Excel
Back to jkp-ads.com

Ron de Bruin
Excel Automation

Microsoft MVP Program

Send mail with link to workbook

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

If you want to let your Colleagues/Co workers now that you have created a workbook that you want to share with them you can use the following subroutine to create a mail with a link to the ActiveWorkbook.

Important :
1: The ActiveWorkbook must be saved on a drive that everyone is connected to
2: The reciever of the mail must also use Outlook

Change the mail address in the macro before you run it.

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

    If ActiveWorkbook.Path <> "" Then
        Set OutApp = CreateObject("Outlook.Application")
        Set OutMail = OutApp.CreateItem(0)

        strbody = "<font size=""3"" face=""Calibri"">" & _
                  "Colleagues,<br><br>" & _
                  "I want to inform you that the next sales Order :<br><B>" & _
                  ActiveWorkbook.Name & "</B> is created.<br>" & _
                  "Click on this link to open the file : " & _
                  "<A HREF=""file://" & ActiveWorkbook.FullName & _
                  """>Link to the file</A>" & _
                  "<br><br>Regards," & _
                  "<br><br>Account Management</font>"

        On Error Resume Next
        With OutMail
            .To = "ron@debruin.nl"
            .CC = ""
            .BCC = ""
            .Subject = ActiveWorkbook.Name
            .HTMLBody = strbody
            .Display   'or use .Send
        End With
        On Error GoTo 0

        Set OutMail = Nothing
        Set OutApp = Nothing
    Else
        MsgBox "The ActiveWorkbook does not have a path, Save the file first."
    End If
End Sub

Tip: If you want that certain code is available in all your workbooks, then use your PERSONAL.XLS or in Excel 2007-2016 your PERSONAL.XLSB file. You can use the same macro then for every file.
Check out this page for help

 

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)