Add a table to e-mail to be sent to multiple addreses

CookieMonster76

Board Regular
Joined
Apr 30, 2015
Messages
200
Hi

I've put together the below to send an e-mail containing a table from Excel to multiple e-mail addresses that are in a list in excel. It works for the 1st address in the list but fails at the point highlighted bold when it comes to the second line.

Is there a way to correct it so it will send however many e-mails I want it to?

Thanks

Paul

Sub SendEmails()
Dim OutlookApp As Object
Dim OutlookMail As Object
Dim i As Integer
Dim lastRow As Long
Dim emailCol As Integer
Dim conditionCol As Integer
Dim xInspect As Object
Dim pageEditor As Object

Set outlook = CreateObject("Outlook.Application")
Set newEmail = outlook.CreateItem(0)

' Define your columns
emailCol = 1 ' Assuming email addresses are in column A
AddresseeCol = 2
ValueCol = 3
MonthCol = 4
conditionCol = 5 ' Assuming your condition (Yes/No) is in column B

' Get the last row with data in column A
lastRow = Cells(Rows.Count, emailCol).End(xlUp).Row

' Create Outlook instance
Set OutlookApp = CreateObject("Outlook.Application")


' Loop through each row
For i = 2 To lastRow ' Assuming the first row is headers
If Cells(i, conditionCol).Value = "Yes" Then
Set OutlookMail = OutlookApp.CreateItem(0)
With OutlookMail
.To = Cells(i, emailCol).Value
.Subject = "West Midlands Pension Fund"
.Body = "Hi " & Cells(i, AddresseeCol).Value & vbLf & vbLf _
& "You owe us " & Cells(i, ValueCol).Value & vbLf & vbLf _
& "in relation to your " & Cells(i, MonthCol).Value & " submission" & vbLf & vbLf _
& "Please let me know if you have any queries." & vbLf & vbLf _
& "Thanks" & vbLf & vbLf _
& "Bev" & vbLf & vbLf

.Display

Set xInspect = newEmail.GetInspector
Set pageEditor = xInspect.WordEditor



Sheets("Table").Range("A1:G9").Copy


pageEditor.Application.Selection.Start = Len(.Body)
pageEditor.Application.Selection.End = pageEditor.Application.Selection.Start
pageEditor.Application.Selection.PasteSpecial (wdFormatPlainText)
.Display
.Send

Set pageEditor = Nothing
Set xInspect = Nothing

End With

Set newEmail = Nothing
Set outlook = Nothing

Set OutlookMail = Nothing
End If
Next i

Set OutlookApp = Nothing
MsgBox "Emails sent successfully!"
End Sub
 

Excel Facts

Add Bullets to Range
Select range. Press Ctrl+1. On Number tab, choose Custom. Type Alt+7 then space then @ sign (using 7 on numeric keypad)
Try:
VBA Code:
Sub SendEmails()
    Application.ScreenUpdating = False
    Dim OutApp As Object, OutMail As Object, rng As Range, v As Variant
    Set rng = Sheets("Table").Range("A1:G9")
    v = Range("A2", Range("A" & Rows.Count).End(xlUp)).Resize(, 5).Value
    Set OutApp = CreateObject("Outlook.Application")
    For i = LBound(v) To UBound(v)
        If v(i, 5) = "Yes" Then
            Set OutMail = OutApp.CreateItem(0)
            With OutMail
                .To = v(i, 1)
                .Subject = "West Midlands Pension Fund"
                .HTMLBody = "Hi " & v(i, 2) & "<br><br>" _
                    & "You owe us " & v(i, 3) & "<br><br>" _
                    & "in relation to your " & v(i, 4) & " submission" & "<br><br>" _
                    & "Please let me know if you have any queries." & "<br><br>" _
                    & "Thanks" & "<br><br>" _
                    & "Bev" & "<br><br>" _
                    & RangetoHTML(rng)
                .Display
            End With
        End If
    Next i
    Application.ScreenUpdating = True
End Sub

Function RangetoHTML(rng As Range)
    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"
    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
    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
    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=")
    TempWB.Close savechanges:=False
    Kill TempFile
    Set ts = Nothing
    Set fso = Nothing
    Set TempWB = Nothing
End Function
 
Upvote 0
Solution

Forum statistics

Threads
1,223,885
Messages
6,175,181
Members
452,615
Latest member
bogeys2birdies

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