Microsoft Excel

Ron de Bruin
Excel Automation

Microsoft MVP Program

Mail one Sheet With Outlook 2011

The code on this page is tested in Lion OS X  and up with Excel 2011 and create the mail in Outlook 2011.

Read this page for Tips:  Tips for changing the Mac Outlook mail examples

Because there are a few bugs in VBA SendMail in Excel and there is no Outlook object model in Outlook 2011 like there is in Outlook for Windows we Run a AppleScript string with the built-in VBA MacScript function in the mail examples to get the same or better result.

Note: To run the mail examples you must copy the macro of your choice and also two functions named MailFromMacWithOutlook and KillFileOnMac that you find on the bottom of this page. If you want to test more then one macro you only have to copy the two functions one time.

 

Example

The following subroutine sends a newly created workbook with just the ActiveSheet.
It is saving the workbook before mailing it with a date/time stamp.
After the file is sent the workbook will be deleted from your hard disk or moved to the Trash.

Change the mail address in the macro before you run it, if you want to use multiple recipients separate them with an ,

Important: Read also the information below the macro.

Sub Mail_ActiveSheet_In_Excel2011()
'For Excel 2011 for the Mac and Outlook 2011
    Dim FileExtStr As String
    Dim FileFormatNum As Long
    Dim Sourcewb As Workbook
    Dim Destwb As Workbook
    Dim TempFilePath As String
    Dim TempFileName As String

    If Val(Application.Version) < 14 Then Exit Sub

    With Application
        .ScreenUpdating = False
        .EnableEvents = False
    End With

    Set Sourcewb = ActiveWorkbook

    'Copy the ActiveSheet to a new workbook
    'You can also use Sheets("MySheetName").Copy
    ActiveSheet.Copy
    Set Destwb = ActiveWorkbook

    'Determine file extension/format
    With Destwb
        Select Case Sourcewb.FileFormat
        Case 52: FileExtStr = ".xlsx": FileFormatNum = 52
        Case 53:
            If .HasVBProject Then
                FileExtStr = ".xlsm": FileFormatNum = 53
            Else
                FileExtStr = ".xlsx": FileFormatNum = 52
            End If
        Case 57: FileExtStr = ".xls": FileFormatNum = 57
        Case Else: FileExtStr = ".xlsb": FileFormatNum = 51
        End Select
    End With

    '    'Change all cells in the worksheet to values if you want
    '    With Destwb.Sheets(1).UsedRange
    '        .Cells.Copy
    '        .Cells.PasteSpecial xlPasteValues
    '        .Cells(1).Select
    '    End With
    '    Application.CutCopyMode = False

    'Save the new workbook/Mail it/Delete it
    'If you want to change the file name then change only TempFileName
    TempFilePath = MacScript("return (path to documents folder) as string")
    TempFileName = "Part of " & Sourcewb.Name & " " _
                 & Format(Now, "dd-mmm-yy h-mm-ss")

    With Destwb
        .SaveAs TempFilePath & TempFileName & FileExtStr, FileFormat:=FileFormatNum
        MailFromMacwithOutlook bodycontent:="Hi there", _
                    mailsubject:="Mail activesheet test", _
                    toaddress:="ron@debruin.nl", _
                    ccaddress:="", _
                    bccaddress:="", _
                    attachment:=.FullName, _
                    displaymail:=False
        .Close SaveChanges:=False
    End With

    Set Destwb = Nothing

    KillFileOnMac TempFilePath & TempFileName & FileExtStr
 
    With Application
        .ScreenUpdating = True
        .EnableEvents = True
    End With
End Sub

You can also use the following line if you know the sheet you want to mail :
Sheets("Sheet5").Copy
It doesn't have to be the active sheet used at that time.

 

Important Functions

Copy both functions below in a normal module of your workbook.
Without the functions the macro(s) above will not work.

Note: If you want to test more then one macro you only have to copy the two functions one time.

Function MailFromMacwithOutlook(bodycontent As String, mailsubject As String, _
            toaddress As String, ccaddress As String, bccaddress As String, _
                          attachment As String, displaymail As Boolean)
'Ron de Bruin, function to Mail with Outlook for the Mac, 19-Aug-2013
    Dim scriptToRun As String

    scriptToRun = scriptToRun & "tell application " & _
                  Chr(34) & "Microsoft Outlook" & Chr(34) & Chr(13)

    scriptToRun = scriptToRun & _
     "set NewMail to make new outgoing message with properties" & _
       "{content:""" & bodycontent & """, subject:""" & mailsubject & """}" & Chr(13)
       
    scriptToRun = scriptToRun & "tell NewMail" & Chr(13)
    If toaddress <> "" Then
        scriptToRun = scriptToRun & "set toaddressList to {" & _
                  Chr(34) & Replace(toaddress, ",", """,""") & Chr(34) & "}" & Chr(13)
        scriptToRun = scriptToRun & "repeat with i from 1 to count toaddressList" & Chr(13)
        scriptToRun = scriptToRun & "make new to recipient at end of to recipients with " & _
                     "properties {email address:{address:item i of toaddressList}}" & Chr(13)
        scriptToRun = scriptToRun & "end repeat" & Chr(13)
    End If
    If ccaddress <> "" Then
        scriptToRun = scriptToRun & "set ccaddressList to {" & _
                  Chr(34) & Replace(ccaddress, ",", """,""") & Chr(34) & "}" & Chr(13)
        scriptToRun = scriptToRun & "repeat with i from 1 to count ccaddressList" & Chr(13)
        scriptToRun = scriptToRun & "make new cc recipient at end of cc recipients with " & _
                     "properties {email address:{address:item i of ccaddressList}}" & Chr(13)
        scriptToRun = scriptToRun & "end repeat" & Chr(13)
    End If
    If bccaddress <> "" Then
        scriptToRun = scriptToRun & "set bccaddressList to {" & _
                  Chr(34) & Replace(bccaddress, ",", """,""") & Chr(34) & "}" & Chr(13)
        scriptToRun = scriptToRun & "repeat with i from 1 to count bccaddressList" & Chr(13)
        scriptToRun = scriptToRun & "make new bcc recipient at end of bcc recipients with " & _
                     "properties {email address:{address:item i of bccaddressList}}" & Chr(13)
        scriptToRun = scriptToRun & "end repeat" & Chr(13)
    End If
    If attachment <> "" Then
        scriptToRun = scriptToRun & "set attachmentList to {" & _
                  Chr(34) & Replace(attachment, ",", """,""") & Chr(34) & "}" & Chr(13)
        scriptToRun = scriptToRun & "repeat with i from 1 to count attachmentList" & Chr(13)
        scriptToRun = scriptToRun & "make new attachment at end of attachments with " & _
                        "properties {file:item i of attachmentList}" & Chr(13)
        scriptToRun = scriptToRun & "end repeat" & Chr(13)
    End If
    scriptToRun = scriptToRun & "end tell" & Chr(13)

    If displaymail = False Then
        scriptToRun = scriptToRun & "send NewMail" & Chr(13)
    Else
        scriptToRun = scriptToRun & "open NewMail" & Chr(13)
        scriptToRun = scriptToRun & "activate NewMail" & Chr(13)
    End If
    scriptToRun = scriptToRun & "end tell" & Chr(13)

    If Len(toaddress) + Len(ccaddress) + Len(bccaddress) = 0 Or mailsubject = "" Then
        MsgBox "There is no To, CC or BCC address or Subject for this mail"
        Exit Function
    Else
        On Error Resume Next
        MacScript (scriptToRun)
        On Error GoTo 0
    End If
End Function


Function KillFileOnMac(Filestr As String)
'Ron de Bruin, 30-July-2012
'Delete files from a Mac.
'Uses AppleScript to avoid the problem with long file names
    Dim ScriptToKillFile As String
    ScriptToKillFile = "tell application " & Chr(34) & _
                       "Finder" & Chr(34) & Chr(13)
    ScriptToKillFile = ScriptToKillFile & _
                 "do shell script ""rm "" & quoted form of posix path of " & _
                  Chr(34) & Filestr & Chr(34) & Chr(13)
    ScriptToKillFile = ScriptToKillFile & "end tell"

    On Error Resume Next
    MacScript (ScriptToKillFile)
    On Error GoTo 0
End Function