Using VBA to Email copied Excel information

Papa_Don

New Member
Joined
Jan 22, 2015
Messages
38
Hi group,

Please advise me if this is the wrong forum to post to.

I've been working to have the VBA code inside an Excel spreadsheet to create a new Outlook email and then paste some copied data from that spreadsheet into this new email. It seems to be doing everything I need it to do except to actually SEND then email. Can you tell me what I'm missing that will do this?

Here's my code:

Sub Mail_Selection_Range_Outlook_Body()


Dim rng As Range
Dim OutApp As Object
Dim OutMail As Object
pRow = 2
propID = Sheets("Prop List").Cells(pRow, 1).Value
emailAdd = Sheets("Email List").Cells(pRow, 2).Value
' ActiveSheet.Range("$A$1:$R$" & lEndRow).AutoFilter Field:=2, Criteria1:=propID


Set rng = Nothing
' Only send the visible cells in the selection.


Set rng = Sheets("Listing").Range("A1:D4").SpecialCells(xlCellTypeVisible)


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)




With OutMail
.To = emailAdd
.CC = ""
.BCC = ""
.Subject = "This is the Subject line"
.HTMLBody = RangetoHTML(rng)
' In place of the following statement, you can use ".Display" to
' display the e-mail message.
.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)


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


Clearly I'm missing some kind of command that actually sends and closes the email. Can you tell me what it is and where to place it (in the Subroutine or the Function?).

In advance, thanks for your help!

Don
 

Excel Facts

Copy a format multiple times
Select a formatted range. Double-click the Format Painter (left side of Home tab). You can paste formatting multiple times. Esc to stop
It seems to be doing everything I need it to do except to actually SEND then email. Can you tell me what I'm missing that will do this?
Try .Send instead of .Display.

PS please use CODE tags - the # icon in the message editor - because it makes the code more readable.
 
Upvote 0
John,

Thanks for the response. It worked perfectly. Sorry about the failure to use the CODE tags. I didn't realize to do that.

As a follow-up question, I need to add some text to the body of the email and before I add the rng (variable for Range). Since this is in essence a "copy and paste" of the range in Excel, how do I add text to the body?

Code:
[COLOR=#000000][FONT=Consolas]With OutMail[/FONT][/COLOR]        
        .To = "ron@debruin.nl"
        .CC = ""
        .BCC = ""
        .Subject = "This is the Subject line" [COLOR=#000000][FONT=Consolas]        
        .HTMLBody = RangetoHTML(rng)[/FONT][/COLOR]

I see the ".HTMLBody" which inserts the copied range. Can I enter something to the effect of

Code:
[COLOR=#000000][FONT=Consolas]With OutMail[/FONT][/COLOR]        
        .To = "ron@debruin.nl"
        .CC = ""
        .BCC = ""
        .Subject = "This is the Subject line"
        .Body = "Some kind of Message." & vbNewLine[COLOR=#000000][FONT=Consolas]        
        .HTMLBody = RangetoHTML(rng)[/FONT][/COLOR]

Or is there some other way I need to do this?

Again, thanks for the help.
 
Upvote 0
John, I meant to tell you that I did try to insert the .Body = "Text message added" above the .HTMLBody = RangeToHTML(rng) with no success. Hopefully you can direct me as how to insert both a message and the range.

Don
 
Upvote 0
Try:
Code:
    .HTMLBody = "Text above Excel cells" & vbNewLine & _
                RangetoHTML(Rng) & vbNewLine & _
                "Text below Excel cells"
 
Upvote 0
John,

The code listed above works partially. The only thing not working is that "Text below Excel Cells": A new line below the Range is not being inserted. I've tried adding a second "& vbNewLine" with no success. This is important to give that extra line as, I'd like to add the user's "Signature" if that's possible below the final text.

Thoughts?

Again, thank you greatly for your help.

Don
 
Upvote 0
John (and anyone else interested),

I've figured out the issue: Since the body of the message is HTML, it's best to use HTML syntax to format, add lines, etc. Therefore the coding now looks like this:

Code:
.HTMLBody = "Text above Excel cells. " & "(less than sign)br(greater than sign)br" & _  
            RangetoHTML(rng) & "(less than sign)br(greater than sign)br" & "Text below Excel cells"

This works perfectly!

John, thanks for your help. It has been greatly appreciated.

Don
 
Upvote 0
Don, putting the extra text in HTML strings is a good idea, but it doesn't quite work on my Outlook because I have an anti-virus scanner which appends its signature to the bottom of every sent email. Although the sent email looks OK in Outlook (because the signature is added after sending), the result in the recipient's Inbox is:

Text above Excel cells
Range of cells
Anti-virus signature
Text below Excel cells

I think this happens because the string returned by RangetoHTML is a complete HTML string with < html > and < body> tags and closing tags, and your method appends the extra HTML strings outside these tags. Ideally, the HTML for the extra text should be inserted in the correct places inside the string returned by RangetoHTML, however this would require careful parsing of the string.

Here is another method which uses a modified version of RangetoHTML which accepts 2 optional arguments for the extra text:
Code:
'http://www.rondebruin.nl/win/s1/outlook/bmail2.htm
'modified to include optional arguments for text above and below the range of cells
Function RangetoHTML(rng As Range, Optional textAbove As String, Optional textBelow As String)
' 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
    Dim r As Long, lines As Variant
    
    TempFile = Environ$("temp") & "\" & Format(Now, "dd-mm-yy h-mm-ss") & ".htm"

    'Copy the range and create a new workbook to paste the data in
    rng.Copy
    Set TempWB = Workbooks.Add(1)
    With TempWB.Sheets(1)
        r = 1
        If textAbove <> "" Then
            lines = Split(textAbove, vbNewLine)
            .Cells(r, 1).Resize(UBound(lines) + 1, 1).Value = Application.WorksheetFunction.Transpose(lines)
            r = r + UBound(lines) + 1
        End If
        .Cells(r, 1).PasteSpecial Paste:=8
        .Cells(r, 1).PasteSpecial xlPasteValues, , False, False
        .Cells(r, 1).PasteSpecial xlPasteFormats, , False, False
        .Cells(r, 1).Select
        If textBelow <> "" Then
            lines = Split(textBelow, vbNewLine)
            .Cells(r + rng.Rows.Count, 1).Resize(UBound(lines) + 1, 1).Value = Application.WorksheetFunction.Transpose(lines)
        End If
        .Cells(1, 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
    
    'Close TempWB - moved here, before reading htm file
    TempWB.Close savechanges:=False
    
    '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=")

    'Delete the htm file we used in this function
    Kill TempFile

    Set ts = Nothing
    Set fso = Nothing
    Set TempWB = Nothing
End Function
Call it like this:
Code:
        .HTMLBody = RangetoHTML(rng, "Text above Excel cells.", "Text below Excel cells." & vbNewLine & "End of email.")
Multiple lines can be specified in the extra text by using vbNewLine between each line.
 
Last edited:
Upvote 0
John, I'll try this later today to see what happens. I don't have anything that appends to the signature. But I have added a "signature" doing this:
Code:
Signature = "(less than sign)BODY style=font-size:12pt;font-family:Calibri(greater than sign)Thank You,(less than sign)br(greater than sign)(less than sign)br(greater than sign)(less than sign)br(greater than sign)" & _            "Franchise Revenue Management Operations(less than sign)br(greater than sign)" & _
            "Starwood Hotels & Resorts Worldwide(less than sign)br(greater than sign)" & _
            "Phone: 123-456-7890(less than sign)/BODY(greater than sign)"

And the final output looks like this:

Code:
.HTMLBody = "(less than sign)BODY style=font-size:12pt;font-family:Calibri(greater than sign)(less than sign)p(greater than sign)Text above Excel cells" & "(less than sign)br(greater than sign)(less than sign)br(greater than sign)" & _                RangetoHTML(rng) & "(less than sign)br(greater than sign)(less than sign)br(greater than sign)" & _
                "Text below Excel cells" & "(less than sign)br(greater than sign)(less than sign)br(greater than sign)" & "Additional Text.(less than sign)br(greater than sign)(less than sign)br(greater than sign)" & Signature & "(less than sign)/p(greater than sign)(less than sign)/BODY(greater than sign)"


FYI.... I tried inserting the actual .htm file that holds the signature. However it didn't like the jpeg pictures I had in it. Thus I had to scrap that idea. But the above worked perfectly.

I'll try yours later today and get back with you.

Again, thanks for your interest and your help!

Don
 
Upvote 0

Forum statistics

Threads
1,215,011
Messages
6,122,680
Members
449,091
Latest member
peppernaut

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