Send Emails to recipients in column with Outlook

tradeaccepted

New Member
Joined
Jun 11, 2013
Messages
33
Hello,

I edited Ron DeBruins Excel VBA to Outlook email code below. Original code: (http://www.rondebruin.nl/win/s1/outlook/bmail2.htm)

My Excel sheet has Email Addresses listed in Column C.

The code runs successfully, but it changes the To value inside one newly opened email message. What I'm looking for is, if I have 10 email addresses in column C, how could I change my code to have Outlook open 10 separate new message windows.


Code:
Sub Mail_Selection_Range_Outlook_Body()'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
    Dim strbody As String
    Dim SigString As String
    Dim Signature As String
    Dim lastRow As Long
    Dim Rng1 As Range
    
    'Find the last email address in column C.
    lastRow = Range("C:C").Find("*", Range("C1"), Searchdirection:=xlPrevious).Row
    Set Rng1 = Range(Cells(2, "C"), Cells(lastRow, "C"))
    
    
    
    'Add signature to the email body
    SigString = Environ("appdata") & _
                "\Microsoft\Signatures\New.htm"
    If Dir(SigString) <> "" Then
        Signature = GetBoiler(SigString)
    Else
        Signature = ""
    End If
    'Signaute code end
    
        
    'Start selection script
    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("Credentials").Range("K2:L7").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)
    
    'Loop though the emails in Column C
    For Each cel In Rng1
    
 
        On Error Resume Next
        With OutMail
            .To = cel.Value
            .CC = ""
            .BCC = ""
            .Subject = ""
            .HTMLBody = RangetoHTML(Rng)
            .Display   'or use .Send
        End With
        On Error GoTo 0
        
    Next cel

    Set OutMail = Nothing
    Set OutApp = Nothing
End Sub
 

Excel Facts

Show numbers in thousands?
Use a custom number format of #,##0,K. Each comma after the final 0 will divide the displayed number by another thousand
The code looks fairly good to me. It's already set to loop through each row and set the To field to the email address in column C for that row.

The only thing I would change is the lastRow variable, but I'm not positive it would cause an issue. I've never used the Find function in that way. This is how I typically find the last row:
Code:
lastRow = Cells(Rows.Count, 3).End(xlUp).Row
 
Upvote 0
The code looks fairly good to me. It's already set to loop through each row and set the To field to the email address in column C for that row.

The only thing I would change is the lastRow variable, but I'm not positive it would cause an issue. I've never used the Find function in that way. This is how I typically find the last row:
Code:
lastRow = Cells(Rows.Count, 3).End(xlUp).Row



Thanks for getting back to me. The code executes fine with no errors, but i'm looking to have a new email message open for each new TO address.
Currently one New Message window opens from Outlook, and then you can see the Values changing inside the single open email. Once the script finishes, the last row will be the one that is displayed in the email.

Instead of this I am looking to have a new email message open for each new row.

This is what the script is currently doing:
AjR0kOl.gif
 
Upvote 0
Try this by modifying the the last part of the code.

Code:
[COLOR=#0000cd]    Set OutApp = CreateObject("Outlook.Application")
[/COLOR]
    [COLOR=#d3d3d3]'[/COLOR][COLOR=#d3d3d3]Set OutMail = OutApp.CreateItem(0)[/COLOR][COLOR=#d3d3d3]'<--- previously[/COLOR][COLOR=#0000cd][COLOR=#0000cd]
[/COLOR]    [/COLOR][COLOR=#d3d3d3]'Loop though the emails in Column C[/COLOR][COLOR=#0000cd]
    For Each cel In Rng1
        [/COLOR][COLOR=#ff0000]Set OutMail = OutApp.CreateItem(0)     [/COLOR][COLOR=#d3d3d3] '<--- move here[/COLOR][COLOR=#0000cd]
        On Error Resume Next
        With OutMail
            .To = cel.Value
            .CC = ""
            .BCC = ""
            .Subject = ""
            .HTMLBody = RangeToHTML(Rng)
            .Display   'or use .Send
        End With
        On Error GoTo 0
        [/COLOR][COLOR=#ff0000]Set OutMail = Nothing[/COLOR][COLOR=#d3d3d3]         '<-- add this[/COLOR][COLOR=#0000cd]
    Next cel

    Set OutMail = Nothing
    Set OutApp = Nothing[/COLOR]
[COLOR=#0000cd]End sub[/COLOR]
 
Upvote 0
Try this by modifying the the last part of the code.

Code:
[COLOR=#0000cd]    Set OutApp = CreateObject("Outlook.Application")
[/COLOR]
    [COLOR=#d3d3d3]'[/COLOR][COLOR=#d3d3d3]Set OutMail = OutApp.CreateItem(0)[/COLOR][COLOR=#d3d3d3]'<--- previously[/COLOR][COLOR=#0000cd][COLOR=#0000cd]
[/COLOR]    [/COLOR][COLOR=#d3d3d3]'Loop though the emails in Column C[/COLOR][COLOR=#0000cd]
    For Each cel In Rng1
        [/COLOR][COLOR=#ff0000]Set OutMail = OutApp.CreateItem(0)     [/COLOR][COLOR=#d3d3d3] '<--- move here[/COLOR][COLOR=#0000cd]
        On Error Resume Next
        With OutMail
            .To = cel.Value
            .CC = ""
            .BCC = ""
            .Subject = ""
            .HTMLBody = RangeToHTML(Rng)
            .Display   'or use .Send
        End With
        On Error GoTo 0
        [/COLOR][COLOR=#ff0000]Set OutMail = Nothing[/COLOR][COLOR=#d3d3d3]         '<-- add this[/COLOR][COLOR=#0000cd]
    Next cel

    Set OutMail = Nothing
    Set OutApp = Nothing[/COLOR]
[COLOR=#0000cd]End sub[/COLOR]


lhartono, you are a gentleman and a scholar! Thank you kindly.
 
Upvote 0

Forum statistics

Threads
1,223,228
Messages
6,170,871
Members
452,363
Latest member
merico17

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