Microsoft Excel

Ron de Bruin
Excel Automation

Microsoft MVP Program

Mail a row or rows to each person in a range with Outlook

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 1

Read this :
1) The code is not working if your data is in a Table
2) The first row in the range must have Headers
3) Turn off AutoFilter before you use the code
4) Be sure that the sheet with the data is the active worksheet

In your worksheet you must have :

In column A : Names of the students or ?
In column B:H : Information about the student or ?

We filter the range A1:H? for every unique name in the name column (column A in this example)
For every unique name we create a new file with only the data of that person and send it to the mail address it find with the VLookup function in the worksheet "Mailinfo".

Important: You must create this worksheet manual and add the names and mail addresses one time.
Add a worksheet to your workbook with the name "Mailinfo" with in column A the names
and in column B the mail addresses of every possible person in your Name column..

How do I Change filter range and filter column? :
In this example I use the filter range A1:H? (we use all the rows on the sheet)
You can change the filter range and filter column in this two code lines in the macro.

Set FilterRange = Ash.Range("A1:H" & Ash.Rows.Count)
FieldNum = 1
'Filter column = A because the filter range start in A

Copy the macro below in a Standard module.

Sub Send_Row_Or_Rows_Attachment_In_Excel2011()
'For Excel 2011 for the Mac and Outlook 2011
    Dim rng As Range
    Dim Ash As Worksheet
    Dim Cws As Worksheet
    Dim Rcount As Long
    Dim Rnum As Long
    Dim FilterRange As Range
    Dim FieldNum As Integer
    Dim mailAddress As String
    Dim Destwb As Workbook
    Dim TempFilePath As String
    Dim TempFileName As String
    Dim FileExtStr As String
    Dim FileFormatNum As Long

    On Error GoTo cleanup

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

    'Set filter sheet, you can also use Sheets("MySheet")
    Set Ash = ActiveSheet

    'Set filter range and filter column (column with names)
    Set FilterRange = Ash.Range("A1:H" & Ash.Rows.Count)
    FieldNum = 1    'Filter column = A, first column in the FilterRange

    'Add a worksheet for the unique name list and copy the unique list in A1
    Set Cws = Worksheets.Add
    FilterRange.Columns(FieldNum).AdvancedFilter _
            Action:=xlFilterCopy, _
            CopyToRange:=Cws.Range("A1"), _
            CriteriaRange:="", Unique:=True

    'Count of the unique values + the header cell
    Rcount = Application.WorksheetFunction.CountA(Cws.Columns(1))

    'If there are unique values start the loop
    If Rcount >= 2 Then
        'Set tempory file path
        TempFilePath = MacScript("return (path to documents folder) as string")
        For Rnum = 2 To Rcount

            'Look for the mail address in the MailInfo worksheet
            mailAddress = ""
            On Error Resume Next
            mailAddress = Application.WorksheetFunction. _
                   VLookup(Cws.Cells(Rnum, 1).Value, _
                          Worksheets("Mailinfo").Range("A1:B" & _
                              Worksheets("Mailinfo").Rows.Count), 2, False)
            On Error GoTo 0

            If mailAddress <> "" Then

                'Filter the FilterRange on the FieldNum column
                FilterRange.AutoFilter Field:=FieldNum, _
                                       Criteria1:=Cws.Cells(Rnum, 1).Value

                'Copy the visible data in a new workbook
                With Ash.AutoFilter.Range
                    On Error Resume Next
                    Set rng = .SpecialCells(xlCellTypeVisible)
                    On Error GoTo 0
                End With

                Set Destwb = Workbooks.Add(xlWBATWorksheet)

                rng.Copy
                With Destwb.Sheets(1)
                    .Cells(1).PasteSpecial Paste:=8
                    .Cells(1).PasteSpecial Paste:=xlPasteValues
                    .Cells(1).PasteSpecial Paste:=xlPasteFormats
                    .Cells(1).Select
                    Application.CutCopyMode = False
                End With

                'Create a file name, if you want to change 
                'the file name then change only TempFileName
                TempFileName = "Your data of " & Ash.Parent.Name _
                             & " " & Format(Now, "dd-mmm-yy h-mm-ss")

                'You can also use a different file format if you want
                FileExtStr = ".xlsx": FileFormatNum = 52

                With Destwb
                    .SaveAs TempFilePath & TempFileName & FileExtStr, _
                            FileFormat:=FileFormatNum

                    MailFromMacwithOutlook _
                                    bodycontent:="Hi " & Cws.Cells(Rnum, 1).Value, _
                                    mailsubject:="Mail Row or Rows 1", _
                                    toaddress:=mailAddress, _
                                    ccaddress:="", bccaddress:="", _
                                    attachment:=.FullName, _
                                    displaymail:=False

                    .Close SaveChanges:=False
                End With

                KillFileOnMac TempFilePath & TempFileName & FileExtStr

            End If

            'Close AutoFilter
            Ash.AutoFilterMode = False

        Next Rnum
    End If

cleanup:
    Application.DisplayAlerts = False
    Cws.Delete
    Application.DisplayAlerts = True

    With Application
        .EnableEvents = True
        .ScreenUpdating = True
    End With
End Sub
 

Example 2

Read this :
1) The code is not working if your data is in a Table
2) The first row in the range must have Headers
3) Turn off AutoFilter before you use the code
4) Be sure that the sheet with the data is the active worksheet

In your worksheet you must have :

In column A : Names of the students or ?
In column B : E-mail addresses
In column C:H : Information about the student or ?

Note: Every row must have a mail address in column B

We filter the range A1:H? for every unique mail address in column B.
For every unique mail address we create a new file with only the records with that
mail address and send it to that mail address.

How do I Change filter range and filter column? :
In this example I use the filter range A1:H? (we use all the rows on the sheet)
You can change the filter range and filter column in this two code lines in the macro.

Set FilterRange = Ash.Range("A1:H" & Ash.Rows.Count)
FieldNum = 2
'Filter column = B because the filter range start in A

Copy the macro below in a Standard module.

Sub Send_Row_Or_Rows_Attachment_In_Excel2011_2()
'For Excel 2011 for the Mac and Outlook 2011
    Dim rng As Range
    Dim Ash As Worksheet
    Dim Cws As Worksheet
    Dim Rcount As Long
    Dim Rnum As Long
    Dim FilterRange As Range
    Dim FieldNum As Integer
    Dim Destwb As Workbook
    Dim TempFilePath As String
    Dim TempFileName As String
    Dim FileExtStr As String
    Dim FileFormatNum As Long
    Dim I As Long

    On Error GoTo cleanup

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

    'Set filter sheet, you can also use Sheets("MySheet")
    Set Ash = ActiveSheet

    'Set filter range and filter column (column with e-mail addresses)
    Set FilterRange = Ash.Range("A1:H" & Ash.Rows.Count)
    FieldNum = 2    'Filter column = B because FilterRange start in column A

    'Add a worksheet for the unique list and copy the unique list in A1
    Set Cws = Worksheets.Add
    FilterRange.Columns(FieldNum).AdvancedFilter _
            Action:=xlFilterCopy, _
            CopyToRange:=Cws.Range("A1"), _
            CriteriaRange:="", Unique:=True

    'Count of the unique values + the header cell
    Rcount = Application.WorksheetFunction.CountA(Cws.Columns(1))

    'If there are unique values start the loop
    If Rcount >= 2 Then
        'Set tempory file path
        TempFilePath = MacScript("return (path to documents folder) as string")

        For Rnum = 2 To Rcount

            'If the unique value is a mail addres create a mail
            If Cws.Cells(Rnum, 1).Value Like "?*@?*.?*" Then

                'Filter the FilterRange on the FieldNum column
                FilterRange.AutoFilter Field:=FieldNum, _
                                       Criteria1:=Cws.Cells(Rnum, 1).Value

                'Copy the visible data in a new workbook
                With Ash.AutoFilter.Range
                    On Error Resume Next
                    Set rng = .SpecialCells(xlCellTypeVisible)
                    On Error GoTo 0
                End With

                Set Destwb = Workbooks.Add(xlWBATWorksheet)

                rng.Copy
                With Destwb.Sheets(1)
                    .Cells(1).PasteSpecial Paste:=8
                    .Cells(1).PasteSpecial Paste:=xlPasteValues
                    .Cells(1).PasteSpecial Paste:=xlPasteFormats
                    .Cells(1).Select
                    Application.CutCopyMode = False
                End With

                'Create a file name, if you want to change
                'the file name then change only TempFileName
                TempFileName = "Your data of " & Ash.Parent.Name _
                             & " " & Format(Now, "dd-mmm-yy h-mm-ss")
                'You can also use a different file format if you want
                FileExtStr = ".xlsx": FileFormatNum = 52

                With Destwb
                    .SaveAs TempFilePath & TempFileName & FileExtStr, _
                        FileFormat:=FileFormatNum

                    MailFromMacwithOutlook _
                                    bodycontent:="Hi " & Sheets(1).Cells(2, 1).Value, _
                                    mailsubject:="Mail Row or Rows 2", _
                                    toaddress:=Cws.Cells(Rnum, 1).Value, _
                                    ccaddress:="", bccaddress:="", _
                                    attachment:=.FullName, _
                                    displaymail:=False

                    .Close SaveChanges:=False
                End With

                KillFileOnMac TempFilePath & TempFileName & FileExtStr

            End If

            'Close AutoFilter
            Ash.AutoFilterMode = False

        Next Rnum
    End If

cleanup:
    Application.DisplayAlerts = False
    Cws.Delete
    Application.DisplayAlerts = True

    With Application
        .EnableEvents = True
        .ScreenUpdating = True
    End With
End Sub

 

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