Sending Multiple E-mails with specific range if cell has adress

DidierB

New Member
Joined
May 23, 2020
Messages
6
Office Version
  1. 365
Platform
  1. Windows
Hi,

I am kind off new to VBA and i an trying to tackle a problem i have. And am not finding a sollution.

I have a column of adresses that get filled in depending on other sheets. There are 150 possible lines.

What i am trying to do

When C32 has adress send range (J12:U35) from sheet 1 to this adress C32
When C33 has adress send range (J12:U35) from sheet 2 to this adress C33
.... C181

I also need to send this from a specific adress (always the same) and with a specific subject that is on the sheet 1,2... page (C2)

I can send a mail with a range to a specific adress but i cant find how i have to check the cells and send to this mail.
I also don't know if it is possible for a code that can do this without copying it 150 times

I tried so many things my macro is totally broken now

Thanks in advance

Best Regards
Didier
 

Excel Facts

Why does 9 mean SUM in SUBTOTAL?
It is because Sum is the 9th alphabetically in Average, Count, CountA, Max, Min, Product, StDev.S, StDev.P, Sum, VAR.S, VAR.P.
This is what i have now that is working.
CodeFrom Rondebruin.nl
I can send it this way but i have to copy it 150 times and i would like to not do that :)
Is it even possible to automate this ?

Thanks

VBA 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

    Set rng = Nothing
    On Error Resume Next
    'Only the visible cells in the selection
    Set rng = Sheets("1").Range("J12:U35").SpecialCells(xlCellTypeVisible)
    'You can also use a fixed range if you want
    'Set rng = Sheets("YourSheet").Range("D4:D12").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 = Sheets("1").Range("C2")
        .CC = ""
        .BCC = ""
        .Subject = Sheets("1").Range("C2")
        .HTMLBody = RangetoHTML(rng)
        .Send   'or use .Display
    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
 
Upvote 0
.
Try this :

VBA Code:
Option Explicit

Sub sendmail()
   Dim OutApp       As Object
   Dim OutMail      As Object
   Dim SigString    As String
   Dim Signature, EmailTo, CCto, Subj, msg, Filepath As String
   Dim ws           As Worksheet
   Dim cel          As Range
   Dim LR           As Long
   Dim rng As Range
   
   Set ws = Sheets("1")
   Set rng = Sheets("1").Range("J12:U35")   '<-- Set the sheet and range to be copied into body of email.
  
   Set OutApp = CreateObject("Outlook.Application")
   Set OutMail = OutApp.CreateItem(0)
   
   With ws
      LR = .Cells.Find("*", .Cells(.Rows.Count, .Columns.Count), SearchOrder:=xlByRows, _
                       SearchDirection:=xlPrevious).Row
      'If Not .AutoFilterMode Then
      '   .Range("A3:P3").AutoFilter
      'End If
      '.Range("A3:P" & LR).AutoFilter Field:=16, Criteria1:="<>"
      If .Range("C32:C181" & LR).Cells.Count > 1 Then
     
         For Each cel In .Range("C32:C181" & LR)
            If cel.Value <> "" Then
                EmailTo = .Cells(cel.Row, "C").Value
                CCto = ""
                Subj = .Range("C2").Value
                msg = "This is your message ..."
               
                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 = EmailTo
                   .CC = CCto
                   .BCC = ""
                   .Subject = Subj
                   .HTMLBody = msg & "<br><br>" & "Please review the following : " & RangetoHTML(rng)
                   .Display   '.Send   'or use .Display
                End With
            End If
         Next cel
      End If
   End With

   On Error GoTo 0
   Set OutMail = Nothing
   Set OutApp = Nothing

   With Application
      .EnableEvents = True
      .ScreenUpdating = True
   End With
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"
    '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
 
Upvote 0
Hi Logit,

Thanks for your reply.

Isnt this going to send the same range ?

The range is on 150 different sheets.

So sheet1 sheet2 ....
And always a different mailing adress.

Thanks in advance
 
Upvote 0
Please post a copy of your workbook with just enough information to demonstrate your needs. You'll need to use a Cloud site such as www.DropBox.com or similar.
 
Upvote 0

Forum statistics

Threads
1,214,606
Messages
6,120,490
Members
448,967
Latest member
visheshkotha

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