• Hi All

    Please note that at the Chandoo.org Forums there is Zero Tolerance to Spam

    Post Spam and you Will Be Deleted as a User

    Hui...

  • When starting a new post, to receive a quicker and more targeted answer, Please include a sample file in the initial post.

Emailing sheet to selected recipitents

Hi guys,

I have a basic send range macro which allows me to send a selection of my worksheet to a recipitent.

What I need to do is when I press my button for the macro to run, is then a list to appear with pre-saved email addresses so I can select who I want to send the message to.

I can see online how to send an email to multiple addresses at the same time, but what I need is to have the multiple addresses appear and to be able to select the 1 in which I need to send it to at that time (as this will change each time), and not send the message to all of the addresses.

Thanks.
 
Is it mandatory the email addresses remain invisible except when selecting who to send the emails to ? If the answer is "No" I have a solution for you.
 
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

  Set ws = Sheets("MRM")
  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("P3:P" & LR).SpecialCells(xlCellTypeVisible).Cells.Count > 1 Then
        For Each cel In .Range("P4:P" & LR).SpecialCells(xlCellTypeVisible)
            EmailTo = .Cells(cel.Row, "J").Value
            CCto = .Cells(cel.Row, "K").Value
            Subj = .Cells(cel.Row, "L").Value
            Filepath = .Cells(cel.Row, "M").Value
            msg = .Cells(cel.Row, "N").Value

            With Application
              .EnableEvents = False
              .ScreenUpdating = False
            End With
            Set OutApp = CreateObject("Outlook.Application")
            Set OutMail = OutApp.CreateItem(0)

            SigString = Environ("appdata") & _
                        "\Microsoft\Signatures\mrm.htm"

            If Dir(SigString) <> "" Then
              Signature = GetBoiler(SigString)
            Else
              Signature = ""
            End If
            On Error Resume Next
            With OutMail
              .To = EmailTo
              .CC = CCto
              .BCC = ""
              .Subject = Subj
              .HTMLBody = msg & "<br>" & Signature
              '.body = msg & vbNewLine & vbNewLine & Signature
              ' .Attachments.Add Filepath 'Uncomment this Line if you've added attachments
              .Display  '.Send  'or use .Display
            End With
        Next cel
      End If
      .AutoFilterMode = False
  End With

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

  With Application
      .EnableEvents = True
      .ScreenUpdating = True
  End With
End Sub

Function GetBoiler(ByVal sFile As String) As String
  '**** Kusleika
  Dim fso          As Object
  Dim ts          As Object
  Set fso = CreateObject("Scripting.FileSystemObject")
  Set ts = fso.GetFile(sFile).OpenAsTextStream(1, -2)
  GetBoiler = ts.readall
  ts.Close
End Function
 

Attachments

  • WORKS Send Mail.xlsm
    40.5 KB · Views: 10
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

  Set ws = Sheets("MRM")
  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("P3:P" & LR).SpecialCells(xlCellTypeVisible).Cells.Count > 1 Then
        For Each cel In .Range("P4:P" & LR).SpecialCells(xlCellTypeVisible)
            EmailTo = .Cells(cel.Row, "J").Value
            CCto = .Cells(cel.Row, "K").Value
            Subj = .Cells(cel.Row, "L").Value
            Filepath = .Cells(cel.Row, "M").Value
            msg = .Cells(cel.Row, "N").Value

            With Application
              .EnableEvents = False
              .ScreenUpdating = False
            End With
            Set OutApp = CreateObject("Outlook.Application")
            Set OutMail = OutApp.CreateItem(0)

            SigString = Environ("appdata") & _
                        "\Microsoft\Signatures\mrm.htm"

            If Dir(SigString) <> "" Then
              Signature = GetBoiler(SigString)
            Else
              Signature = ""
            End If
            On Error Resume Next
            With OutMail
              .To = EmailTo
              .CC = CCto
              .BCC = ""
              .Subject = Subj
              .HTMLBody = msg & "<br>" & Signature
              '.body = msg & vbNewLine & vbNewLine & Signature
              ' .Attachments.Add Filepath 'Uncomment this Line if you've added attachments
              .Display  '.Send  'or use .Display
            End With
        Next cel
      End If
      .AutoFilterMode = False
  End With

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

  With Application
      .EnableEvents = True
      .ScreenUpdating = True
  End With
End Sub

Function GetBoiler(ByVal sFile As String) As String
  '**** Kusleika
  Dim fso          As Object
  Dim ts          As Object
  Set fso = CreateObject("Scripting.FileSystemObject")
  Set ts = fso.GetFile(sFile).OpenAsTextStream(1, -2)
  GetBoiler = ts.readall
  ts.Close
End Function


This is great thanks a lot! Is there anyway change the message, as this needs to be a selection from another sheet?

Thanks
 
The only way to do that is to have a UserForm. You can add the Dropdown list into the form and have it load the list of email addresses from a hidden sheet for example, each time it initializes.

References:
http://www.contextures.com/xlUserForm02.html

How would I then get the email to send from a userform? I understand how to get their email address load using the form, but then not how to send the email to one selected?

Thanks
 
Questions:

#1 - Will the message always be the same for all emails ?

#2 - If the answer to #1 is "No", where is the data located on the other sheet ?

#3 - Will the data from question #2 always be in the same location ?

#4 - What is the data that comprises the message ?
 
Questions:

#1 - Will the message always be the same for all emails ?

#2 - If the answer to #1 is "No", where is the data located on the other sheet ?

#3 - Will the data from question #2 always be in the same location ?

#4 - What is the data that comprises the message ?


1 - no, it is a range of cells which gives customer info + product ordered to our supplier, so the range of cells will always be the same but the information in those cells will be different each time.

2 - the information is filled in on my 'order sheet'

3 - yes always the same location and same range of cells that needs to be emailed

4 - range of cells emailed into the body of the email

Hope this helps, thanks.
 
Here is the macro code:

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("MRM")
‘The next line requires editing for the Sheet and Range of data to copy.
  Set rng = Sheets("Sheet1").Range("B4:J10")

  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("P3:P" & LR).SpecialCells(xlCellTypeVisible).Cells.Count > 1 Then
        For Each cel In .Range("P4:P" & LR).SpecialCells(xlCellTypeVisible)
            EmailTo = .Cells(cel.Row, "J").Value
            CCto = .Cells(cel.Row, "K").Value
            Subj = .Cells(cel.Row, "L").Value
            Filepath = .Cells(cel.Row, "M").Value
            msg = .Cells(cel.Row, "N").Value

            With Application
              .EnableEvents = False
              .ScreenUpdating = False
            End With
            Set OutApp = CreateObject("Outlook.Application")
            Set OutMail = OutApp.CreateItem(0)

            SigString = Environ("appdata") & _
                        "\Microsoft\Signatures\mrm.htm"

            If Dir(SigString) <> "" Then
              Signature = GetBoiler(SigString)
            Else
              Signature = ""
            End If
            On Error Resume Next
            With OutMail
              .To = EmailTo
              .CC = CCto
              .BCC = ""
              .Subject = Subj
‘Use the following line to include range of data in email body
              .HTMLBody = msg & "<br><br>" & "Please review the following : " & RangetoHTML(rng)
              '.body = msg & vbNewLine & vbNewLine & Signature
              ' .Attachments.Add Filepath 'Uncomment this Line if you've added attachments
              .Display  '.Send  'or use .Display
            End With
        Next cel
      End If
      .AutoFilterMode = False
  End With

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

  With Application
      .EnableEvents = True
      .ScreenUpdating = True
  End With
End Sub

Function GetBoiler(ByVal sFile As String) As String
  '**** Kusleika
  Dim fso          As Object
  Dim ts          As Object
  Set fso = CreateObject("Scripting.FileSystemObject")
  Set ts = fso.GetFile(sFile).OpenAsTextStream(1, -2)
  GetBoiler = ts.ReadAll
  ts.Close
End Function

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

And the complete workbook attached.

The DOC file is the macro code with the new lines of code highlighted in yellow, in case you want to know what was added to the original.
 

Attachments

  • WORKS Multi Address w Range Paste.xlsm
    45.6 KB · Views: 13
  • Macro Code.docx
    13.6 KB · Views: 8
Last edited:
Here is the macro code:

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("MRM")
‘The next line requires editing for the Sheet and Range of data to copy.
  Set rng = Sheets("Sheet1").Range("B4:J10")

  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("P3:P" & LR).SpecialCells(xlCellTypeVisible).Cells.Count > 1 Then
        For Each cel In .Range("P4:P" & LR).SpecialCells(xlCellTypeVisible)
            EmailTo = .Cells(cel.Row, "J").Value
            CCto = .Cells(cel.Row, "K").Value
            Subj = .Cells(cel.Row, "L").Value
            Filepath = .Cells(cel.Row, "M").Value
            msg = .Cells(cel.Row, "N").Value

            With Application
              .EnableEvents = False
              .ScreenUpdating = False
            End With
            Set OutApp = CreateObject("Outlook.Application")
            Set OutMail = OutApp.CreateItem(0)

            SigString = Environ("appdata") & _
                        "\Microsoft\Signatures\mrm.htm"

            If Dir(SigString) <> "" Then
              Signature = GetBoiler(SigString)
            Else
              Signature = ""
            End If
            On Error Resume Next
            With OutMail
              .To = EmailTo
              .CC = CCto
              .BCC = ""
              .Subject = Subj
‘Use the following line to include range of data in email body
              .HTMLBody = msg & "<br><br>" & "Please review the following : " & RangetoHTML(rng)
              '.body = msg & vbNewLine & vbNewLine & Signature
              ' .Attachments.Add Filepath 'Uncomment this Line if you've added attachments
              .Display  '.Send  'or use .Display
            End With
        Next cel
      End If
      .AutoFilterMode = False
  End With

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

  With Application
      .EnableEvents = True
      .ScreenUpdating = True
  End With
End Sub

Function GetBoiler(ByVal sFile As String) As String
  '**** Kusleika
  Dim fso          As Object
  Dim ts          As Object
  Set fso = CreateObject("Scripting.FileSystemObject")
  Set ts = fso.GetFile(sFile).OpenAsTextStream(1, -2)
  GetBoiler = ts.ReadAll
  ts.Close
End Function

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

And the complete workbook attached.

The DOC file is the macro code with the new lines of code highlighted in yellow, in case you want to know what was added to the original.




I've managed to do it with your original suggestion of a Userform. I've altered my code to reference my combox value so it picks up the selection from the drop down & emails to that person.

Code:
   .Item.To = Me.ComboBox1.Value
 
Back
Top