Sending email with multiple rows to multiple users

vkknava

New Member
Joined
Nov 7, 2012
Messages
4
I need to send 1 email to each user appearing multiple times in the excel with the row data. Can someone help with a vb script?

Below is my excel sheet

emailfullnameDataDateDurationUsage
user@email.comName1Sample
4/23/2021 1:45​
10 days 22 hours 02 mins 55 secs
100​
user@email.comName1Sample1
4/23/2021 21:01​
10 days 22 hours 02 mins 55 secs
50​
user1@email.comName2Sample2
4/24/2021 21:01​
11 days 22 hours 02 mins 55 secs
51​
user1@email.comName3Sample3
4/25/2021 21:01​
12 days 22 hours 02 mins 55 secs
52​
user1@email.comName4Sample3
4/26/2021 21:01​
13 days 22 hours 02 mins 55 secs
53​


user@email.com should get an email like below with some text message

emailfullnameDataDateDurationUsage
user@email.comName1Sample
4/23/2021 1:45​
10 days 22 hours 02 mins 55 secs
100​
user@email.comName1Sample1
4/23/2021 21:01​
10 days 22 hours 02 mins 55 secs
50​

user1@email.com should get email as below with some text message

emailfullnameDataDateDurationUsage
user1@email.comName2Sample2
4/24/2021 21:01​
11 days 22 hours 02 mins 55 secs
51​
user1@email.comName3Sample3
4/25/2021 21:01​
12 days 22 hours 02 mins 55 secs
52​
user1@email.comName4Sample3
4/26/2021 21:01​
13 days 22 hours 02 mins 55 secs
53​
 

Excel Facts

Last used cell?
Press Ctrl+End to move to what Excel thinks is the last used cell.
Try:
VBA Code:
Sub CreateEmail()
    Application.ScreenUpdating = False
    Dim OutApp As Object, OutMail As Object, rng As Range, i As Long, v As Variant
    v = Range("A2", Range("A" & Rows.Count).End(xlUp)).Value
    Set OutApp = CreateObject("Outlook.Application")
    With CreateObject("Scripting.Dictionary")
        For i = 1 To UBound(v, 1)
            If Not .Exists(v(i, 1)) Then
                .Add v(i, 1), Nothing
                With Range("A1")
                    .CurrentRegion.AutoFilter 1, v(i, 1)
                    Set rng = ActiveSheet.AutoFilter.Range.Offset(1)
                    Set OutMail = OutApp.CreateItem(0)
                    With OutMail
                        .To = v(i, 1)
                        .Subject = "This is a test message."
                        .HTMLBody = RangetoHTML(rng)
                        .Display
                    End With
                End With
            End If
        Next i
    End With
    Range("A1").AutoFilter
    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

Forum statistics

Threads
1,214,429
Messages
6,119,428
Members
448,896
Latest member
MadMarty

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