98.7% Of all customers recommend us, we're so confident about our results we publish all reviews and stats
View Live Stats View ReviewsForum home » Delegate support and help forum » Microsoft Excel VBA Training and help » Email Generation with IF Statement
Email Generation with IF Statement
Resolved · Urgent Priority · Version 2010
Adrian has attended:
Excel VBA Introduction course
Excel VBA Intermediate course
Excel Intermediate course
Email Generation with IF Statement
Hi
I am creating a macro to essentially generate an email. The issue I have concern the body of the email - Essentially if cell D4 is above 50000 then include range B2:E11, other wise only include Range A. The code below is where it seems to go wrong - Everything else generates just fine. Your help would be very much appreciated:
Set rng = Nothing
On Error Resume Next
'Only the visible cells in the selection
Set rng = Sheets("Input").Range("B4:E11").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 = "
.CC = "
.BCC = ""
.Subject = Range("B12")
.HTMLBody = Range
If Range("D4") >= 50000 Then
rng.Select
Selection.PasteSpecial Paste:=xlValues, Operation:=xlNone, SkipBlanks:=False, Transpose:=False
Application.CutCopyMode = False
Else
Range("A1").Select
End If
.Display
RE: Email Generation with IF Statement
Hi Adrian,
Thank you for the forum question.
You cannot put anything else in the body than text, but you can do what you want, if I understand you right. You will need the function you will find in the code below. If you copy the code and test it in a new workbook you will find out that it is working. The code below will, if D4 is >= to 50000 take the date in the range A1:A10 and put it in the body of the email.
I hope this can help you.
Sub Test()
Dim OutApp As Object
Dim OutMail As Object
Dim rng As Range
Set rng = Range("a1:a10")
Set OutApp = CreateObject("Outlook.Application")
If Range("D4") >= 50000 Then
Set OutMail = OutApp.CreateItem(0)
On Error Resume Next
With OutMail
.To = "test"
.CC = ""
.BCC = ""
.Subject = Range("B12")
.HTMLBody = RangetoHTML(rng)
.Display
End With
Else
Range("A1").Select
End If
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.Select
Cells.EntireRow.AutoFit
Cells.EntireColumn.AutoFit
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
Kind regards
Jens Bonde
Microsoft Office Specialist Trainer
Tel: 0207 987 3777
Best STL - https://www.stl-training.co.uk
98%+ recommend us
London's leader with UK wide delivery in Microsoft Office training and management training to global brands, FTSE 100, SME's and the public sector
RE: Email Generation with IF Statement
Hi Jens
Thank you for your quick response!
Unfortunately its not quite what I needed. Essentially if D4 is over 50000 then the email populates correctly, however I still want the email to populate if its less than 50000, but just with a blank body (the title etc to be the same as before). Is this possible?
RE: Email Generation with IF Statement
Hi Adrian,
Try:
Sub Test()
Dim OutApp As Object
Dim OutMail As Object
Dim rng As Range
Set rng = Range("a1:a10")
Set OutApp = CreateObject("Outlook.Application")
If Range("D4") >= 50000 Then
Set OutMail = OutApp.CreateItem(0)
On Error Resume Next
With OutMail
.To = "test"
.CC = ""
.BCC = ""
.Subject = Range("B12")
.HTMLBody = RangetoHTML(rng)
.Display
End With
elseif Range("D4") < 50000 Then
Set OutMail = OutApp.CreateItem(0)
On Error Resume Next
With OutMail
.To = "test"
.CC = ""
.BCC = ""
.Subject = Range("B12")
.HTMLBody = ""
.Display
End With
Else
Range("A1").Select
End If
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.Select
Cells.EntireRow.AutoFit
Cells.EntireColumn.AutoFit
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
Read more: https://www.stl-training.co.uk/post-37114-email-generation-if-statement.html #ixzz4Nef7j7yr
Kind regards
Jens Bonde
Microsoft Office Specialist Trainer
Tel: 0207 987 3777
Best STL - https://www.stl-training.co.uk
98%+ recommend us
London's leader with UK wide delivery in Microsoft Office training and management training to global brands, FTSE 100, SME's and the public sector
Training information:
Welcome. Please choose your application (eg. Excel) and then post your question. Our Microsoft Qualified trainers will then respond within 24 hours (working days). Frequently Asked Questions
Any suggestions, questions or comments? Please post in the Improve the forum thread. |
Excel tip:Move or Highlight CellsUse any of your movement keys, cursor, Home, End, PgUp or PgDn to highlight cells rows or columns by holding down the Shift key as you move. |