Using VBA to send Outlook Email / Sent on Behalf Of Name

Papa_Don

New Member
Joined
Jan 22, 2015
Messages
38
Group,

I've created a macro that works very well except I'm unable to get the ".SentOnBehalfOf" to work. Here's the code:
Code:
Sub Mail_Selection_Range_Outlook_Body()
 
Dim rng As Range
Dim OutApp As Object
Dim OutMail As Object
Dim greeting As String
Dim Signature As String
Dim paragraph1 As String
Dim paragraph2 As String
Dim paragraph3 As String
Dim paragraph4 As String
Dim paragraph5 As String
Dim auditDate As String
Dim rateLoadYear As String
Dim emailAlias As String
 
 
Set rng = Nothing
' Only send the visible cells in the selection.
 
Set rng = Sheets("Listing").Range("B1:R" & lEndRow).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)
 
Signature = "<BODY style=font-size:12pt;font-family:Calibri>Thank You,<br><br><br>" & _
            "Franchise Revenue Management Operations<br>" & _
            "Starwood Hotels & Resorts Worldwide<br>" & _
            "Phone: 770-857-2071</BODY>"
 
auditDate = Sheets("Email Listing").Range("O1").Value
 
rateLoadYear = Sheets("Email Listing").Range("I7").Value
 
greeting = Sheets("Email Listing").Range("K5").Value
 
paragraph1 = Sheets("Email Listing").Range("K11").Value
 
paragraph2 = Sheets("Email Listing").Range("K17").Value
 
paragraph3 = Sheets("Email Listing").Range("K23").Value
 
paragraph4 = Sheets("Email Listing").Range("K29").Value
 
paragraph5 = Sheets("Email Listing").Range("K35").Value
 
With OutMail
    .SentOnBehalfOfName = emailAlias
    .To = emailAdd
    .CC = ""
    .BCC = ""
    .Subject = "Corporate Transient Rate Audit " & auditDate & " / " & propName & " (#" & propID & ")"
    .HTMLBody = "<BODY style=font-size:11pt;font-family:Calibri>" & greeting & "<br><br>" & _
                paragraph1 & "<br><br>" & _
                paragraph2 & "<br><br>" & _
                paragraph3 & "<br><br>" & _
                paragraph4 & "<br><br>" & _
                RangetoHTML(rng) & "<br><br>" & _
                "<span background-color: #FFFF00""><b>" & paragraph5 & "</b></span>" & "<br><br>" & _
                Signature & "</BODY>"
    .Send
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

I recognize that the user must be authorized to use the "SentOnBehalfOfName". In this case the user has that authorization. However the coding still doesn't work. Any thoughts on what I might be missing?

In advance, thanks for your help.

Don
 

Excel Facts

Shade all formula cells
To shade all formula cells: Home, Find & Select, Formulas to select all formulas. Then apply a light fill color.
When you say it doesn't work, what happens? Does it throw an exception? Or run but just not send it?

/AJ
 
Upvote 0
Adam, thankfully no exception is thrown. It simply ignores the ".SentOnBehalfName" and uses the users email name/address as the sent by. The emails are sent and everything else is perfect. I have absolutely no other issues. But it would be best if I ensure the "Sent by On Behalf Of:" works correctly.

Thoughts?

Thanks for your help.

Don
 
Upvote 0
As a follow-up, I did find the fix to this. I moved the ".SendOnBehalfName" down below the "To:" such that it looks like this:
Code:
    With OutMail
        .To = emailAdd
        .SentOnBehalfOfName = emailAlias
        .CC = ""
        .BCC = ""
        .Subject = "Corporate Transient Rate Audit " & auditDate & " / " & propName & " (#" & propID & ")"
        .HTMLBody = "" & greeting & ""
        .Send
    End With

I've tested this and it works as it should.

Good luck to all!

Don
 
Upvote 0

Forum statistics

Threads
1,224,828
Messages
6,181,209
Members
453,023
Latest member
alabaz

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