VBA to include email addresses

VOR

Board Regular
Joined
Apr 11, 2009
Messages
59
Office Version
  1. 365
  2. 2019
Platform
  1. Windows
  2. MacOS
Hello all,
I am currently using the VBA code below to send an email which works perfectly but would like to adapt it on another project to use email addresses listed on another sheet instead of the ones in the code.
Can anyone help adapt this please?



VBA Code:
Sub Mail_Selection_Range_Outlook_Body_Handover()
'For Tips see: http://www.rondebruin.nl/win/winmail/Outlook/tips.htm
'Don't forget to copy the function RangetoHTML in the module.
'Working in Excel 2000-2016
    Dim rng As Range
    Dim OutApp As Object
    Dim OutMail As Object

    Set rng = Nothing
    On Error Resume Next
    'Only the visible cells in the selection
    'Set rng = Selection.SpecialCells(xlCellTypeVisible)
    'You can also use a fixed range if you want
    Set rng = Sheets("Numbers").Range("a1:z50") '.SpecialCells(xlCellTypeVisible)'
    On Error GoTo 0

    If rng Is Nothing Then
        MsgBox "The selection is not a range or the sheet is protected" & _
               vbNewLine & "please correct and try again.", vbOKOnly
        Exit Sub
    End If

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

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

    On Error Resume Next
    With OutMail
        .To = "Joe.Bloggs@Test.co.uk;"
        .CC = ""
        .BCC = ""
        .Subject = "Test " & Format(Date, "dd/MM/yyyy")
        .HTMLBody = RangetoHTML(rng)
        .Display   'or use .Display or Send
    End With
    On Error GoTo 0

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

    Set OutMail = Nothing
    Set OutApp = Nothing
End Sub

Function RangetoHTML(rng As Range)
' Changed by Ron de Bruin 28-Oct-2006
' Working in Office 2000-2016
    Dim fso As Object
    Dim ts As Object
    Dim TempFile As String
    Dim TempWB As Workbook

    TempFile = Environ$("temp") & "\" & Format(Now, "dd-mm-yy h-mm-ss") & ".htm"

    'Copy the range and create a new workbook to past the data in
    rng.Copy
    Set TempWB = Workbooks.Add(1)
    With TempWB.Sheets(1)
        .Cells(1).PasteSpecial Paste:=8
        .Cells(1).PasteSpecial xlPasteValues, , False, False
        .Cells(1).PasteSpecial xlPasteFormats, , False, False
        .Cells(1).Select
        Application.CutCopyMode = False
        On Error Resume Next
        .DrawingObjects.Visible = True
        .DrawingObjects.Delete
        On Error GoTo 0
    End With

    'Publish the sheet to a htm file
    With TempWB.PublishObjects.Add( _
         SourceType:=xlSourceRange, _
         Filename:=TempFile, _
         Sheet:=TempWB.Sheets(1).Name, _
         Source:=TempWB.Sheets(1).UsedRange.Address, _
         HtmlType:=xlHtmlStatic)
        .Publish (True)
    End With

    'Read all data from the htm file into RangetoHTML
    Set fso = CreateObject("Scripting.FileSystemObject")
    Set ts = fso.GetFile(TempFile).OpenAsTextStream(1, -2)
    RangetoHTML = ts.readall
    ts.Close
    RangetoHTML = Replace(RangetoHTML, "align=center x:publishsource=", _
                          "align=left x:publishsource=")

    'Close TempWB
    TempWB.Close savechanges:=False

    'Delete the htm file we used in this function
    Kill TempFile

    Set ts = Nothing
    Set fso = Nothing
    Set TempWB = Nothing
End Function
 

Excel Facts

When they said...
When they said you are going to "Excel at life", they meant you "will be doing Excel your whole life".
Hi see if this update to Ron's code does what you want

Rich (BB code):
Sub Mail_Selection_Range_Outlook_Body_Handover()
'For Tips see: http://www.rondebruin.nl/win/winmail/Outlook/tips.htm
'Don't forget to copy the function RangetoHTML in the module.
'Working in Excel 2000-2016
    Dim rng As Range
    Dim OutApp As Object, OutMail As Object
    Dim eMailArr As Variant, eMailAddress As Variant
    
    Set rng = Nothing
    On Error Resume Next
'Only the visible cells in the selection
'Set rng = Selection.SpecialCells(xlCellTypeVisible)
'You can also use a fixed range if you want
    Set rng = Sheets("Numbers").Range("a1:z50") '.SpecialCells(xlCellTypeVisible)'
'get email addresses - change fixed range as required or make dynamic
    eMailArr = Worksheets("Email Addresses").Range("A1:A20").Value
    On Error GoTo exitsub
    
    If rng Is Nothing Then
        MsgBox "The selection is not a range or the sheet is protected" & _
        vbNewLine & "please correct and try again.", vbOKOnly
        Exit Sub
    End If
    
    With Application
        .EnableEvents = False: .ScreenUpdating = False
    End With
    
    For Each eMailAddress In eMailArr
'check value looks like email address
    If eMailAddress Like "?*@?*.?*" Then
        Set OutApp = CreateObject("Outlook.Application")
        Set OutMail = OutApp.CreateItem(0)
        With OutMail
            .To = eMailAddress
            .CC = ""
            .BCC = ""
            .Subject = "Test " & Format(Date, "dd/MM/yyyy")
            .HTMLBody = RangetoHTML(rng)
            .Display   'or use .Display or Send
        End With
    End If
'clear object variables from memory
        Set OutMail = Nothing
        Set OutApp = Nothing
    Next
    
exitsub:
    With Application
        .EnableEvents = True: .ScreenUpdating = True
    End With
    If Err <> 0 Then MsgBox (Error(Err)), 48, "Error"
End Sub

You will need to either add a sheet named "Email Addresses" OR change the name in code shown in BOLD to match sheet name as required.
Also, The data range in the sheet is fixed but you can amend in need to make it dynamic.

I included in Ron's code his test for to ensure value in range looks like an email.

Hope helpful

Dave
 
Upvote 0
Hi see if this update to Ron's code does what you want

Rich (BB code):
Sub Mail_Selection_Range_Outlook_Body_Handover()
'For Tips see: http://www.rondebruin.nl/win/winmail/Outlook/tips.htm
'Don't forget to copy the function RangetoHTML in the module.
'Working in Excel 2000-2016
    Dim rng As Range
    Dim OutApp As Object, OutMail As Object
    Dim eMailArr As Variant, eMailAddress As Variant
   
    Set rng = Nothing
    On Error Resume Next
'Only the visible cells in the selection
'Set rng = Selection.SpecialCells(xlCellTypeVisible)
'You can also use a fixed range if you want
    Set rng = Sheets("Numbers").Range("a1:z50") '.SpecialCells(xlCellTypeVisible)'
'get email addresses - change fixed range as required or make dynamic
    eMailArr = Worksheets("Email Addresses").Range("A1:A20").Value
    On Error GoTo exitsub
   
    If rng Is Nothing Then
        MsgBox "The selection is not a range or the sheet is protected" & _
        vbNewLine & "please correct and try again.", vbOKOnly
        Exit Sub
    End If
   
    With Application
        .EnableEvents = False: .ScreenUpdating = False
    End With
   
    For Each eMailAddress In eMailArr
'check value looks like email address
    If eMailAddress Like "?*@?*.?*" Then
        Set OutApp = CreateObject("Outlook.Application")
        Set OutMail = OutApp.CreateItem(0)
        With OutMail
            .To = eMailAddress
            .CC = ""
            .BCC = ""
            .Subject = "Test " & Format(Date, "dd/MM/yyyy")
            .HTMLBody = RangetoHTML(rng)
            .Display   'or use .Display or Send
        End With
    End If
'clear object variables from memory
        Set OutMail = Nothing
        Set OutApp = Nothing
    Next
   
exitsub:
    With Application
        .EnableEvents = True: .ScreenUpdating = True
    End With
    If Err <> 0 Then MsgBox (Error(Err)), 48, "Error"
End Sub

You will need to either add a sheet named "Email Addresses" OR change the name in code shown in BOLD to match sheet name as required.
Also, The data range in the sheet is fixed but you can amend in need to make it dynamic.

I included in Ron's code his test for to ensure value in range looks like an email.

Hope helpful

Dave
Thanks Dave,
The updated code works but sends an individual email to each of the recipients. Can it be adapted to send one email to all the recipients?


Thanks
Russ
 
Upvote 0
Thanks Dave,
The updated code works but sends an individual email to each of the recipients. Can it be adapted to send one email to all the recipients?


Thanks
Russ

untested but try this update

VBA Code:
Sub Mail_Selection_Range_Outlook_Body_Handover()
'For Tips see: http://www.rondebruin.nl/win/winmail/Outlook/tips.htm
'Don't forget to copy the function RangetoHTML in the module.
'Working in Excel 2000-2016
    Dim rng As Range
    Dim OutApp As Object, OutMail As Object
    Dim eMailArr As Variant, eMailAddress As Variant
    Dim addr As String
    
    Set rng = Nothing
    On Error Resume Next
'Only the visible cells in the selection
'Set rng = Selection.SpecialCells(xlCellTypeVisible)
'You can also use a fixed range if you want
    Set rng = Sheets("Numbers").Range("a1:z50") '.SpecialCells(xlCellTypeVisible)'
'get email addresses - change fixed range as required or make dynamic
    eMailArr = Worksheets("Email Addresses").Range("A1:A20").Value
    On Error GoTo exitsub
    
    If rng Is Nothing Then
        MsgBox "The selection is not a range or the sheet is protected" & _
        vbNewLine & "please correct and try again.", vbOKOnly
        Exit Sub
    End If
    
    With Application
        .EnableEvents = False: .ScreenUpdating = False
    End With
    
    For Each eMailAddress In eMailArr
'check value looks like email address
    If eMailAddress Like "?*@?*.?*" Then
        addr = addr & ";" & eMailAddress
    End If
    Next
    If Len(addr) = 0 Then Err.Raise 600, , "Valid eMail Address Not Found"
    
        Set OutApp = CreateObject("Outlook.Application")
        Set OutMail = OutApp.CreateItem(0)
        With OutMail
            .To = addr
            .CC = ""
            .BCC = ""
            .Subject = "Test " & Format(Date, "dd/MM/yyyy")
            .HTMLBody = RangetoHTML(rng)
            .Display   'or use .Display or Send
        End With

'clear object variables from memory
        Set OutMail = Nothing
        Set OutApp = Nothing
        
exitsub:
    With Application
        .EnableEvents = True: .ScreenUpdating = True
    End With
    If Err <> 0 Then MsgBox (Error(Err)), 48, "Error"
End Sub

Dave
 
Upvote 0
untested but try this update

VBA Code:
Sub Mail_Selection_Range_Outlook_Body_Handover()
'For Tips see: http://www.rondebruin.nl/win/winmail/Outlook/tips.htm
'Don't forget to copy the function RangetoHTML in the module.
'Working in Excel 2000-2016
    Dim rng As Range
    Dim OutApp As Object, OutMail As Object
    Dim eMailArr As Variant, eMailAddress As Variant
    Dim addr As String
   
    Set rng = Nothing
    On Error Resume Next
'Only the visible cells in the selection
'Set rng = Selection.SpecialCells(xlCellTypeVisible)
'You can also use a fixed range if you want
    Set rng = Sheets("Numbers").Range("a1:z50") '.SpecialCells(xlCellTypeVisible)'
'get email addresses - change fixed range as required or make dynamic
    eMailArr = Worksheets("Email Addresses").Range("A1:A20").Value
    On Error GoTo exitsub
   
    If rng Is Nothing Then
        MsgBox "The selection is not a range or the sheet is protected" & _
        vbNewLine & "please correct and try again.", vbOKOnly
        Exit Sub
    End If
   
    With Application
        .EnableEvents = False: .ScreenUpdating = False
    End With
   
    For Each eMailAddress In eMailArr
'check value looks like email address
    If eMailAddress Like "?*@?*.?*" Then
        addr = addr & ";" & eMailAddress
    End If
    Next
    If Len(addr) = 0 Then Err.Raise 600, , "Valid eMail Address Not Found"
   
        Set OutApp = CreateObject("Outlook.Application")
        Set OutMail = OutApp.CreateItem(0)
        With OutMail
            .To = addr
            .CC = ""
            .BCC = ""
            .Subject = "Test " & Format(Date, "dd/MM/yyyy")
            .HTMLBody = RangetoHTML(rng)
            .Display   'or use .Display or Send
        End With

'clear object variables from memory
        Set OutMail = Nothing
        Set OutApp = Nothing
       
exitsub:
    With Application
        .EnableEvents = True: .ScreenUpdating = True
    End With
    If Err <> 0 Then MsgBox (Error(Err)), 48, "Error"
End Sub

Dave
Absolutely perfect. Thank you Dave

Russ
 
Upvote 0

Forum statistics

Threads
1,214,971
Messages
6,122,525
Members
449,088
Latest member
RandomExceller01

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