Send email macro to multiple recipients

laurainwa

New Member
Joined
Dec 23, 2011
Messages
7
I'm using the macro listed below (from RondeBruin) to send a worksheet as an attachment. It works great, except I am sending it to multiple recipients and I have to click the "allow" program to send email for each and every email. Is there a way to just send one email to everyone I need? I need to know what part of this code to delete and what to replace it with. (I don't know really anything about VBA code so I need it in as simple terms as possible. :) )
Sub Mail_ActiveSheet()
'Working in 97-2010
Dim FileExtStr As String
Dim FileFormatNum As Long
Dim Sourcewb As Workbook
Dim Destwb As Workbook
Dim TempFilePath As String
Dim TempFileName As String
Dim I As Long

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

Set Sourcewb = ActiveWorkbook

'Copy the sheet to a new workbook
ActiveSheet.Copy
Set Destwb = ActiveWorkbook

'Determine the Excel version and file extension/format
With Destwb
If Val(Application.Version) < 12 Then
'You use Excel 97-2003
FileExtStr = ".xls": FileFormatNum = -4143
Else
'You use Excel 2007-2010, we exit the sub when your answer is
'NO in the security dialog that you only see when you copy
'an sheet from a xlsm file with macro's disabled.
If Sourcewb.Name = .Name Then
With Application
.ScreenUpdating = True
.EnableEvents = True
End With
MsgBox "Your answer is NO in the security dialog"
Exit Sub
Else
Select Case Sourcewb.FileFormat
Case 51: FileExtStr = ".xlsx": FileFormatNum = 51
Case 52:
If .HasVBProject Then
FileExtStr = ".xlsm": FileFormatNum = 52
Else
FileExtStr = ".xlsx": FileFormatNum = 51
End If
Case 56: FileExtStr = ".xls": FileFormatNum = 56
Case Else: FileExtStr = ".xlsb": FileFormatNum = 50
End Select
End If
End If
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
TempFilePath = Environ$("temp") & "\"
TempFileName = "Part of " & Sourcewb.Name & " " _
& Format(Now, "dd-mmm-yy h-mm-ss")

With Destwb
.SaveAs TempFilePath & TempFileName & FileExtStr, _
FileFormat:=FileFormatNum
On Error Resume Next
For I = 1 To 3
.SendMail "ron@debruin.nl", _
"This is the Subject line"
If Err.Number = 0 Then Exit For
Next I
On Error GoTo 0
.Close SaveChanges:=False
End With

'Delete the file you have send
Kill TempFilePath & TempFileName & FileExtStr

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

Excel Facts

Can you sort left to right?
To sort left-to-right, use the Sort dialog box. Click Options. Choose "Sort left to right"
Hi,

with sendmail you apparently use an array for multiple send addresses
Replace this with and array of the addresses as shown below.
Code:
.SendMail "ron@debruin.nl", _
"This is the Subject line"

If there are loads of recipients you can create the array dynamically from a range of cells on your worksheet but if the list is always the same and only a few it's quicker to hardcode them.
Each address in the array comprises the following snip of code and you add this to the end of the last address in the array before the close bracket in red. You can add as many to the array as you need.
There is a limit but it's hundreds and it shouldn't be a concern.

I hope that's clear enough?

, "(another.address)"

Code:
.SendMail Array("([EMAIL="Fred@yahoo.com"]Fred@yahoo.com[/EMAIL])", "([EMAIL="Jack@yahoo.com"]Jack@yahoo.com[/EMAIL])", "([EMAIL="Jill@yahoo.com"]Jill@yahoo.com[/EMAIL])"[COLOR=red])[/COLOR], _
"This is the Subject line"
 
Upvote 0
Hi and welcome to the Board
Usually, if you are going to send to multiple users, it would be better to use the Outlook model rather than SendMail.
AS a sample I use this to send to a group of people
Code:
Sub Send_Email()
Dim Email_Subject, Email_Send_From, Email_Body As String, i As Integer
Dim Mail_Object, nameList As String, o As Variant
        Email_Send_From = ""
         For i = 7 To 39 'use cells 7 to 39 in column "I" where names are stored
    If Sheets("SHEETNAME").Range("I7").Value <> "" Then
        nameList = nameList & ";" & Sheets("SHEETNAME").Range("I" & i).Value
    End If
Next
        Set Mail_Object = CreateObject("Outlook.Application")
        With Mail_Object.CreateItem(o)
            .Subject = "SUBJECT GOES HERE "
            .To = nameList
            .Body = "BODY TEXT HERE"
            .Attachments.Add "FILEPATH AND FILENAME HERE" 'ActiveWorkbook.FullName
            .Send 'Will send straight away use .display to send manually
End With
        Application.DisplayAlerts = False
End Sub
 
Upvote 0
Hi and welcome to the Board
Usually, if you are going to send to multiple users, it would be better to use the Outlook model rather than SendMail.
AS a sample I use this to send to a group of people
Code:
Sub Send_Email()
Dim Email_Subject, Email_Send_From, Email_Body As String, i As Integer
Dim Mail_Object, nameList As String, o As Variant
        Email_Send_From = ""
         For i = 7 To 39 'use cells 7 to 39 in column "I" where names are stored
    If Sheets("SHEETNAME").Range("I7").Value <> "" Then
        nameList = nameList & ";" & Sheets("SHEETNAME").Range("I" & i).Value
    End If
Next
        Set Mail_Object = CreateObject("Outlook.Application")
        With Mail_Object.CreateItem(o)
            .Subject = "SUBJECT GOES HERE "
            .To = nameList
            .Body = "BODY TEXT HERE"
            .Attachments.Add "FILEPATH AND FILENAME HERE" 'ActiveWorkbook.FullName
            .Send 'Will send straight away use .display to send manually
End With
        Application.DisplayAlerts = False
End Sub

Hi Michael, how can I amend your code so that I send certain sheets to an individual? So sheet a to this person and sheet b to this person etc??

I also need to send it as an attachment however the copy that I send needs to be sent as values only?
 
Upvote 0
Hi Michael

This is what i need to amend to.

Hopefully you can help me. I have commented what i need

Thank You

Code:
Sub Send_Email()
Dim Email_Subject, Email_Send_From, Email_Body As String, i As Integer
Dim Mail_Object, nameList As String, o As Variant
 
 
        '(Before sending email,
        'msgbox are you sure you want to send email's to all individuals in list
        'If yes is selected then send emails
        'else exit sub)'
 
        For i = 2 To 5
        'Sheet names are in Col A2 to A5
        'Email address are in Col B2 to B5
 
        Set Mail_Object = CreateObject("Outlook.Application")
 
        With Mail_Object.CreateItem(o)
            .Subject = "SUBJECT GOES HERE "
            .To = 'COPY SHEET A&i (A2) and email to B&i (B2)'. The sheet that is copied need to be as paste special values'
            .Body = "BODY TEXT HERE"
            .Attachments.Add "FILEPATH AND FILENAME HERE" 'ActiveWorkbook.FullName
            .Send 'Will send straight away use .display to send manually
        End With
        Next i ' Hopefully once the loop has been done i should have emailed everyone in that list'
Application.DisplayAlerts = False
End Sub

<TABLE style="WIDTH: 156pt; BORDER-COLLAPSE: collapse" border=0 cellSpacing=0 cellPadding=0 width=207><COLGROUP><COL style="WIDTH: 64pt; mso-width-source: userset; mso-width-alt: 3108" width=85><COL style="WIDTH: 92pt; mso-width-source: userset; mso-width-alt: 4461" width=122><TBODY><TR style="HEIGHT: 15pt" height=20><TD style="BORDER-BOTTOM: windowtext 0.5pt solid; BORDER-LEFT: windowtext 0.5pt solid; BACKGROUND-COLOR: #002060; WIDTH: 64pt; HEIGHT: 15pt; BORDER-TOP: windowtext 0.5pt solid; BORDER-RIGHT: windowtext 0.5pt solid" class=xl64 height=20 width=85>SHEET NAME</TD><TD style="BORDER-BOTTOM: windowtext 0.5pt solid; BORDER-LEFT: windowtext; BACKGROUND-COLOR: #002060; WIDTH: 92pt; BORDER-TOP: windowtext 0.5pt solid; BORDER-RIGHT: windowtext 0.5pt solid" class=xl64 width=122>MAILING ADDRESS</TD></TR><TR style="HEIGHT: 15pt" height=20><TD style="BORDER-BOTTOM: windowtext 0.5pt solid; BORDER-LEFT: windowtext 0.5pt solid; BACKGROUND-COLOR: transparent; HEIGHT: 15pt; BORDER-TOP: windowtext; BORDER-RIGHT: windowtext 0.5pt solid" class=xl65 height=20>SUE</TD><TD style="BORDER-BOTTOM: windowtext 0.5pt solid; BORDER-LEFT: windowtext; BACKGROUND-COLOR: transparent; BORDER-TOP: windowtext; BORDER-RIGHT: windowtext 0.5pt solid" class=xl65>???</TD></TR><TR style="HEIGHT: 15pt" height=20><TD style="BORDER-BOTTOM: windowtext 0.5pt solid; BORDER-LEFT: windowtext 0.5pt solid; BACKGROUND-COLOR: transparent; HEIGHT: 15pt; BORDER-TOP: windowtext; BORDER-RIGHT: windowtext 0.5pt solid" class=xl65 height=20>JO</TD><TD style="BORDER-BOTTOM: windowtext 0.5pt solid; BORDER-LEFT: windowtext; BACKGROUND-COLOR: transparent; BORDER-TOP: windowtext; BORDER-RIGHT: windowtext 0.5pt solid" class=xl65>???</TD></TR><TR style="HEIGHT: 15pt" height=20><TD style="BORDER-BOTTOM: windowtext 0.5pt solid; BORDER-LEFT: windowtext 0.5pt solid; BACKGROUND-COLOR: transparent; HEIGHT: 15pt; BORDER-TOP: windowtext; BORDER-RIGHT: windowtext 0.5pt solid" class=xl65 height=20>BILL</TD><TD style="BORDER-BOTTOM: windowtext 0.5pt solid; BORDER-LEFT: windowtext; BACKGROUND-COLOR: transparent; BORDER-TOP: windowtext; BORDER-RIGHT: windowtext 0.5pt solid" class=xl65>???</TD></TR><TR style="HEIGHT: 15pt" height=20><TD style="BORDER-BOTTOM: windowtext 0.5pt solid; BORDER-LEFT: windowtext 0.5pt solid; BACKGROUND-COLOR: transparent; HEIGHT: 15pt; BORDER-TOP: windowtext; BORDER-RIGHT: windowtext 0.5pt solid" class=xl65 height=20>SAM</TD><TD style="BORDER-BOTTOM: windowtext 0.5pt solid; BORDER-LEFT: windowtext; BACKGROUND-COLOR: transparent; BORDER-TOP: windowtext; BORDER-RIGHT: windowtext 0.5pt solid" class=xl65>???</TD></TR><TR style="HEIGHT: 15pt" height=20><TD style="BORDER-BOTTOM: windowtext 0.5pt solid; BORDER-LEFT: windowtext 0.5pt solid; BACKGROUND-COLOR: transparent; HEIGHT: 15pt; BORDER-TOP: windowtext; BORDER-RIGHT: windowtext 0.5pt solid" class=xl65 height=20>EDDIE</TD><TD style="BORDER-BOTTOM: windowtext 0.5pt solid; BORDER-LEFT: windowtext; BACKGROUND-COLOR: transparent; BORDER-TOP: windowtext; BORDER-RIGHT: windowtext 0.5pt solid" class=xl65>???</TD></TR></TBODY></TABLE>


If anyone else could help me that would be fab. MERRY CHRISTMAS. It's amazing to have you guys helping even though it is Christmas Eve. Shows alot about you guys. God Bless you all
 
Last edited:
Upvote 0
Hi Michael

This is what i need to amend to.

Hopefully you can help me. I have commented what i need

Thank You

Code:
Sub Send_Email()
Dim Email_Subject, Email_Send_From, Email_Body As String, i As Integer
Dim Mail_Object, nameList As String, o As Variant
 
 
        '(Before sending email,
        'msgbox are you sure you want to send email's to all individuals in list
        'If yes is selected then send emails
        'else exit sub)'
 
        For i = 2 To 5
        'Sheet names are in Col A2 to A5
        'Email address are in Col B2 to B5
 
        Set Mail_Object = CreateObject("Outlook.Application")
 
        With Mail_Object.CreateItem(o)
            .Subject = "SUBJECT GOES HERE "
            .To = 'COPY SHEET A&i (A2) and email to B&i (B2)'. The sheet that is copied need to be as paste special values'
            .Body = "BODY TEXT HERE"
            .Attachments.Add "FILEPATH AND FILENAME HERE" 'ActiveWorkbook.FullName
            .Send 'Will send straight away use .display to send manually
        End With
        Next i ' Hopefully once the loop has been done i should have emailed everyone in that list'
Application.DisplayAlerts = False
End Sub

<TABLE style="WIDTH: 156pt; BORDER-COLLAPSE: collapse" border=0 cellSpacing=0 cellPadding=0 width=207><COLGROUP><COL style="WIDTH: 64pt; mso-width-source: userset; mso-width-alt: 3108" width=85><COL style="WIDTH: 92pt; mso-width-source: userset; mso-width-alt: 4461" width=122><TBODY><TR style="HEIGHT: 15pt" height=20><TD style="BORDER-BOTTOM: windowtext 0.5pt solid; BORDER-LEFT: windowtext 0.5pt solid; BACKGROUND-COLOR: #002060; WIDTH: 64pt; HEIGHT: 15pt; BORDER-TOP: windowtext 0.5pt solid; BORDER-RIGHT: windowtext 0.5pt solid" class=xl64 height=20 width=85>SHEET NAME</TD><TD style="BORDER-BOTTOM: windowtext 0.5pt solid; BORDER-LEFT: windowtext; BACKGROUND-COLOR: #002060; WIDTH: 92pt; BORDER-TOP: windowtext 0.5pt solid; BORDER-RIGHT: windowtext 0.5pt solid" class=xl64 width=122>MAILING ADDRESS</TD></TR><TR style="HEIGHT: 15pt" height=20><TD style="BORDER-BOTTOM: windowtext 0.5pt solid; BORDER-LEFT: windowtext 0.5pt solid; BACKGROUND-COLOR: transparent; HEIGHT: 15pt; BORDER-TOP: windowtext; BORDER-RIGHT: windowtext 0.5pt solid" class=xl65 height=20>SUE</TD><TD style="BORDER-BOTTOM: windowtext 0.5pt solid; BORDER-LEFT: windowtext; BACKGROUND-COLOR: transparent; BORDER-TOP: windowtext; BORDER-RIGHT: windowtext 0.5pt solid" class=xl65>???</TD></TR><TR style="HEIGHT: 15pt" height=20><TD style="BORDER-BOTTOM: windowtext 0.5pt solid; BORDER-LEFT: windowtext 0.5pt solid; BACKGROUND-COLOR: transparent; HEIGHT: 15pt; BORDER-TOP: windowtext; BORDER-RIGHT: windowtext 0.5pt solid" class=xl65 height=20>JO</TD><TD style="BORDER-BOTTOM: windowtext 0.5pt solid; BORDER-LEFT: windowtext; BACKGROUND-COLOR: transparent; BORDER-TOP: windowtext; BORDER-RIGHT: windowtext 0.5pt solid" class=xl65>???</TD></TR><TR style="HEIGHT: 15pt" height=20><TD style="BORDER-BOTTOM: windowtext 0.5pt solid; BORDER-LEFT: windowtext 0.5pt solid; BACKGROUND-COLOR: transparent; HEIGHT: 15pt; BORDER-TOP: windowtext; BORDER-RIGHT: windowtext 0.5pt solid" class=xl65 height=20>BILL</TD><TD style="BORDER-BOTTOM: windowtext 0.5pt solid; BORDER-LEFT: windowtext; BACKGROUND-COLOR: transparent; BORDER-TOP: windowtext; BORDER-RIGHT: windowtext 0.5pt solid" class=xl65>???</TD></TR><TR style="HEIGHT: 15pt" height=20><TD style="BORDER-BOTTOM: windowtext 0.5pt solid; BORDER-LEFT: windowtext 0.5pt solid; BACKGROUND-COLOR: transparent; HEIGHT: 15pt; BORDER-TOP: windowtext; BORDER-RIGHT: windowtext 0.5pt solid" class=xl65 height=20>SAM</TD><TD style="BORDER-BOTTOM: windowtext 0.5pt solid; BORDER-LEFT: windowtext; BACKGROUND-COLOR: transparent; BORDER-TOP: windowtext; BORDER-RIGHT: windowtext 0.5pt solid" class=xl65>???</TD></TR><TR style="HEIGHT: 15pt" height=20><TD style="BORDER-BOTTOM: windowtext 0.5pt solid; BORDER-LEFT: windowtext 0.5pt solid; BACKGROUND-COLOR: transparent; HEIGHT: 15pt; BORDER-TOP: windowtext; BORDER-RIGHT: windowtext 0.5pt solid" class=xl65 height=20>EDDIE</TD><TD style="BORDER-BOTTOM: windowtext 0.5pt solid; BORDER-LEFT: windowtext; BACKGROUND-COLOR: transparent; BORDER-TOP: windowtext; BORDER-RIGHT: windowtext 0.5pt solid" class=xl65>???</TD></TR></TBODY></TABLE>


If anyone else could help me that would be fab. MERRY CHRISTMAS. It's amazing to have you guys helping even though it is Christmas Eve. Shows alot about you guys. God Bless you all

Hi michael, donkeyote

Any luck on the above

Thank you and merry christmas
 
Upvote 0
Sorry...because it's Xmas and we are all having a few drinks and celebrating with family, Mr Excel has to wait a day or two !!
I'll hopefully have a look tomorrow
 
Upvote 0
Sorry...because it's Xmas and we are all having a few drinks and celebrating with family, Mr Excel has to wait a day or two !!
I'll hopefully have a look tomorrow

Thank you and have a lovely day.

I look forward to your reply

Thank you
 
Upvote 0
I've has a look at the code and I think this will do as required
Code:
Sub Send_Email()
Dim Email_Subject, Email_Send_From, Email_Body As String, i As Integer
Dim Mail_Object, nameList As String, o As Variant, ws As Worksheet, ws1 As Worksheet
    With Application
        .ScreenUpdating = False
        .EnableEvents = False
    End With
Set ws = Worksheets("Main") 'Sheet name of recipient list
    ans = MsgBox("Are you sure you want to send email's to all individuals in list ??", vbYesNo)
        If ans = vbNo Then Exit Sub
For i = 2 To 6
    Worksheets(ws.Range("A" & i).Value).Copy
        With Worksheets(ws.Range("A" & i).Value).UsedRange
            .Cells.Copy
            .Cells.PasteSpecial xlPasteValues
        End With
        Application.CutCopyMode = False
    TempFilePath = Environ$("temp") & "\"
    TempFileName = ws.Range("A" & i).Value & " " & Format(Now, "dd-mmm-yy")
    FileExtStr = ".xls"
    FileFormatNum = 56
        With ActiveWorkbook
            .SaveAs TempFilePath & TempFileName & FileExtStr, FileFormat:=FileFormatNum
        End With
        Set Mail_Object = CreateObject("Outlook.Application")
        With Mail_Object.CreateItem(o)
            .Subject = "Your Latest Worksheet "
            .To = ws.Range("B" & i).Value
            .Body = "MESSAGE TEXT HERE"
            .Attachments.Add ActiveWorkbook.FullName
            .display
            '.Send 'Will send straight away use .display to send manually
        End With
        With ActiveWorkbook
            .Close SaveChanges:=False
        End With
    Kill TempFilePath & TempFileName & FileExtStr
    Set OutMail = Nothing
    Set OutApp = Nothing
Next i
    With Application
        .ScreenUpdating = True
        .EnableEvents = True
    End With
End Sub

Note the sheet with the recipients names in the code is called "Main", you can change it to whatever you need.
 
Upvote 0
Sorry also forgot to mention that the E-Mails are set to display not send
to change it, change these lines
Code:
.display ' delete this line
'.Send 'Remove the apostrophe from the start of this line
 
Upvote 0

Forum statistics

Threads
1,215,064
Messages
6,122,942
Members
449,094
Latest member
teemeren

We've detected that you are using an adblocker.

We have a great community of people providing Excel help here, but the hosting costs are enormous. You can help keep this site running by allowing ads on MrExcel.com.
Allow Ads at MrExcel

Which adblocker are you using?

Disable AdBlock

Follow these easy steps to disable AdBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the icon in the browser’s toolbar.
2)Click on the "Pause on this site" option.
Go back

Disable AdBlock Plus

Follow these easy steps to disable AdBlock Plus

1)Click on the icon in the browser’s toolbar.
2)Click on the toggle to disable it for "mrexcel.com".
Go back

Disable uBlock Origin

Follow these easy steps to disable uBlock Origin

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back

Disable uBlock

Follow these easy steps to disable uBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back
Back
Top