vba to send mutiple email from excel range

gleamng

Board Regular
Joined
Oct 8, 2016
Messages
98
Office Version
  1. 365
  2. 2021
  3. 2019
  4. 2016
  5. 2013
  6. 2011
  7. 2010
  8. 2007
  9. 2003 or older
Platform
  1. Windows
  2. MacOS
  3. Mobile
  4. Web
Good day everyone, i need help with sending bulk mails to thousands of recipients on sheet 1 and sent in format in sheets named email format, any help is highly appreciated. below are the sheets named as follows. Sheet1 and EMAIL FORMAT

printSLIP.xlsm
A
1PSN
Sheet1


printSLIP.xlsm
D
6
EMAIL FORMAT
 

Excel Facts

Waterfall charts in Excel?
Office 365 customers have access to Waterfall charts since late 2016. They were added to Excel 2019.
Good day everyone, i need help with sending bulk mails to thousands of recipients from "Sheet1",
the email body format have some fixed information and dynamic information which are captured in the "EMAIL FORMAT" sheet
Any help is highly appreciated, not necessarily in my format but to be seperated just like the email format. below are the sheets named as follows. Sheet1 and EMAIL FORMAT

printSLIP.xlsm
ABCDEFGHIJKLMNOP
1PSNVer No.NAMEM.SMA:MobileClose DateGenderGradeStepE-mailDeductionTotal DeductionGrossMonthlyPayYearMonth
20023992865510366MUDASHIR KHADIJAT AYODEJISTATE CSC80381338411/8/2026Female12-CONPSS2me@you.comTAX=0.00,DEV-LEVYDED=N8.33,HPR COOPDED=N52000.00,NHFDED=N693.98,PAYEE=N1267.74,UNIONDUE=N1601.50,WATERDED=N150.0055,721.5560,057.094,335.542023August
30023962869268011MARIAM VICTORIA STATE CSC81516854601/8/2027Male10-CONPSS3allofus@men.comTAX=0.00,DEV-LEVYDED=N8.33,MAO COOPDED=N28000.00,NHFDED=N619.44,PAYEE=N739.07,UNIONDUE=N952.99,WATERDED=N150.0030,469.8347,649.4117,179.582023August
40023932872591233ALIYU ASISAT BOLAJISTATE CSC703444729921/3/2024Male05-CONPSS5night@day.comTAX=0.00,DEV-LEVYDED=N8.33,IMANDED=N1000.00,NHFDED=N905.48,PAYEE=N3104.52,UNIONDUE=N1862.53,WATERDED=N200.007,080.8693,126.5086,045.642023August
50023902882520968AFASE ALICE STATE CSC80394117086/4/2025FemaleCONHESSPS-073lion@forest.comTAX=0.00,DEV-LEVYDED=N8.33,ENHO COOPDED=N28000.00,KWEHO=N2000.00,NHFDED=N659.30,PAYEE=N2165.73,UNIONDUE=N2001.46,WATERDED=N150.0034,984.8274,640.0039,655.182023August
60023872897034067MONSURAT GANIYU KAMALSTATE CSC803768593010/12/2023Male10-CONPSS3goat@field.comTAX=0.00,DEV-LEVYDED=N8.33,MCI COOPDED=N20000.00,NHFDED=N594.31,PAYEE=N1313.44,UNIONDUE=N1208.63,WATERDED=N150.0023,274.7160,431.5537,156.842023August
70023842897212526HABEEB SILIFAT ABIDOLUSTATE CSC80349583062/5/2025Female14-CONPSS3every@thing.comTAX=0.00,AL-VET COOPDED=N55000.00,DEV-LEVYDED=N8.33,DIRECTCREDITDED=N24420.00,NHFDED=N1058.49,PAYEE=N5246.73,UNIONDUE=N3102.67,WATERDED=N200.0089,036.22114,445.0025,408.782023August
80023812900720844SAIFUDDEEN AHMED OLAYEMISTATE CSC81670863211/1/2024Female07-CONPSS6sold@buying.comTAX=0.00,AGR COOPDED=N50000.00,DEV-LEVYDED=N8.33,NHFDED=N931.70,PAYEE=N3276.49,UNIONDUE=N1922.38,WATERDED=N200.0056,338.9096,118.7539,779.852023August
90023782901149264KAFAYAT MUKAILA AYINDESTATE CSC81662778961/1/2026Male14-CONPSS2mails@google.comTAX=0.00,CONFIDENCE MFB=N7000.00,DEV-LEVYDED=N8.33,DIRECTCREDITDED=N12333.33,HPR COOPDED=N35000.00,NHFDED=N496.60,PAYEE=N1267.74,UNIONDUE=N1601.50,WATERDED=N150.0057,857.5060,057.092,199.592023August
100023752901346137SAMUEL MOHAMMED OLAITANSTATE CSC70388717421/8/2025Male12-CONPSS3phone@calls.comTAX=0.00,DEV-LEVYDED=N8.33,MAO COOPDED=N70000.00,MUSWOWDED=N500.00,NHFDED=N1009.64,PAYEE=N2301.88,UNIONDUE=N1553.29,WATERDED=N200.0075,573.1477,664.452,091.312023August
110023722902566383FATIMA FEMI STATE CSC81086017104/8/2024Female10-CONPSS3help@excel.comTAX=0.00,CHW COOPDED=N57000.00,DEV-LEVYDED=N8.33,IMANDED=N200.00,NACHPNDED=N2000.00,NHFDED=N974.69,PAYEE=N2945.38,UNIONDUE=N2249.29,WATERDED=N150.0065,527.6983,785.5518,257.862023August
Sheet1
Cells with Conditional Formatting
CellConditionCell FormatStop If True
B2:B11Cell ValueduplicatestextNO
B1Cell ValueduplicatestextNO



MAIN HEADING
SUB HEADING
COL P & COL O & DETAILS
PERSONAL DETAILS:
NAME:COL C
VER. NO.COL B
PSN NO.COL A
M.SMA:COL D
CLOSING DATE:COL F
GLCOL H
STEP:COL I
GENDER:COL G
PHONE NO.COL E
E-MAIL ADDRESS:COL J
PAYMENT DETAILS
DEDUCTIONS:COL K
TOTAL DEDUCTION:COL L
GROSS PAY:COL M
NET PAY:COL N


thanks for your continued support
 
Upvote 0
Click here to download your file. Please note that I have added a sheet named "EMAIL FORMAT". Also, if you have thousands of recipients, it may take a while for all the emails to be created and sent. Please note the line in red in the code. This is the code.
Rich (BB code):
Sub CreateEmails()
    Application.ScreenUpdating = False
    Dim OutApp As Object, OutMail As Object, rng As Range, v As Variant, desWS As Worksheet
    Set desWS = Sheets("EMAIL FORMAT")
    v = Sheets("Sheet1").Range("A2", Sheets("Sheet1").Range("A" & Rows.Count).End(xlUp)).Resize(, 16).Value
    Set OutApp = CreateObject("Outlook.Application")
    For i = LBound(v) To UBound(v)
        With desWS
            .Range("A3") = v(i, 16) & " " & v(i, 15) & " DETAILS"
            .Range("B6") = v(i, 3)
            .Range("B8:B16") = WorksheetFunction.Transpose(Array(v(i, 2), v(i, 1), v(i, 4), v(i, 6), v(i, 8), v(i, 9), v(i, 7), v(i, 5), v(i, 10)))
            .Range("B19") = v(i, 11)
            .Range("B24:B26") = WorksheetFunction.Transpose(Array(v(i, 12), v(i, 13), v(i, 14)))
        End With
        Set rng = desWS.Range("A1:B26")
        Set OutMail = OutApp.CreateItem(0)
        With OutMail
            .To = v(i, 10)
            .Subject = desWS.Range("A3")
            .HTMLBody = RangetoHTML(rng)
            .Display 'Change 'Display' to 'Send' to send the emails automatically without seeing them first.
        End With
    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
Click here to download your file. Please note that I have added a sheet named "EMAIL FORMAT". Also, if you have thousands of recipients, it may take a while for all the emails to be created and sent. Please note the line in red in the code. This is the code.
Rich (BB code):
Sub CreateEmails()
    Application.ScreenUpdating = False
    Dim OutApp As Object, OutMail As Object, rng As Range, v As Variant, desWS As Worksheet
    Set desWS = Sheets("EMAIL FORMAT")
    v = Sheets("Sheet1").Range("A2", Sheets("Sheet1").Range("A" & Rows.Count).End(xlUp)).Resize(, 16).Value
    Set OutApp = CreateObject("Outlook.Application")
    For i = LBound(v) To UBound(v)
        With desWS
            .Range("A3") = v(i, 16) & " " & v(i, 15) & " DETAILS"
            .Range("B6") = v(i, 3)
            .Range("B8:B16") = WorksheetFunction.Transpose(Array(v(i, 2), v(i, 1), v(i, 4), v(i, 6), v(i, 8), v(i, 9), v(i, 7), v(i, 5), v(i, 10)))
            .Range("B19") = v(i, 11)
            .Range("B24:B26") = WorksheetFunction.Transpose(Array(v(i, 12), v(i, 13), v(i, 14)))
        End With
        Set rng = desWS.Range("A1:B26")
        Set OutMail = OutApp.CreateItem(0)
        With OutMail
            .To = v(i, 10)
            .Subject = desWS.Range("A3")
            .HTMLBody = RangetoHTML(rng)
            .Display 'Change 'Display' to 'Send' to send the emails automatically without seeing them first.
        End With
    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
Thank you, Thank you, Thank you so much, it worked exactly as i wanted. one last thing please, i added a ".png" picture in column a1 together with the static heading but it doesn't send the picture in the mail, any more help please. once again thanks a lot.
 
Upvote 0
Could you upload a copy of your file which includes the picture to a free site such as www.box.com or www.dropbox.com. Once you do that, mark it for 'Sharing' and you will be given a link to the file that you can post here. Explain in detail what you want to do referring to specific cells, rows, columns and sheets using a few examples from your data (de-sensitized if necessary).
 
Upvote 0
Could you upload a copy of your file which includes the picture to a free site such as www.box.com or www.dropbox.com. Once you do that, mark it for 'Sharing' and you will be given a link to the file that you can post here. Explain in detail what you want to do referring to specific cells, rows, columns and sheets using a few examples from your data (de-sensitized if necessary).
thanks for your prompt response, all i wanted to add to the email is a logo at the top which i want to be received together with the table just as shown in the "email format" sheet. below is the link of the shared file. thank you once more.
 
Upvote 0
Click here for your file. The code is as follows:
VBA Code:
Sub CreateEmails()
    Application.ScreenUpdating = False
    Dim OutApp As Object, OutMail As Object, rng As Range, v As Variant, desWS As Worksheet
    Dim wDoc As Object, wRng As Object
    Set desWS = Sheets("EMAIL FORMAT")
    v = Sheets("Sheet1").Range("A2", Sheets("Sheet1").Range("A" & Rows.Count).End(xlUp)).Resize(, 16).Value
    Set OutApp = CreateObject("Outlook.Application")
    For i = LBound(v) To UBound(v)
        With desWS
            .Range("A4") = v(i, 16) & " " & v(i, 15) & " DETAILS"
            .Range("B7") = v(i, 3)
            .Range("B9:B17") = WorksheetFunction.Transpose(Array(v(i, 2), v(i, 1), v(i, 4), v(i, 6), v(i, 8), v(i, 9), v(i, 7), v(i, 5), v(i, 10)))
            .Range("B20") = v(i, 11)
            .Range("B25:B27") = WorksheetFunction.Transpose(Array(v(i, 12), v(i, 13), v(i, 14)))
        End With
        Set rng = desWS.Range("A1:B27")
        Set OutMail = OutApp.CreateItem(0)
        With OutMail
            .To = v(i, 10)
            .Subject = desWS.Range("A3")
            Set wDoc = OutMail.GetInspector.WordEditor
            Set wRng = wDoc.Range
            rng.Copy
            wRng.Paste
            .Display
        End With
    Next i
    Application.CutCopyMode = False
    Application.ScreenUpdating = True
End Sub
 
Upvote 0

Forum statistics

Threads
1,215,133
Messages
6,123,233
Members
449,092
Latest member
SCleaveland

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