try to email with vba, but more than one sheet and convert to pdf

P

pswanie

im trying to use rons code (below)

1: how can i send sheet1 and sheet2 and sheet3
2: either as attachement or in body but person recieving should not be able
to edit

im gona run it from a commandbutton_click

Sub Mail_Sheet_Outlook_Body()
' Don't forget to copy the function RangetoHTML in the module.
' Working in Office 2000-2007
Dim rng As Range
Dim OutApp As Object
Dim OutMail As Object
With Application
.EnableEvents = False
.ScreenUpdating = False
End With

Set rng = Nothing
Set rng = ActiveSheet.UsedRange
'You can also use a sheet name
'Set rng = Sheets("YourSheet").UsedRange

Set OutApp = CreateObject("Outlook.Application")
OutApp.Session.Logon
Set OutMail = OutApp.CreateItem(0)

On Error Resume Next
With OutMail
.To = "(e-mail address removed)"
.CC = ""
.BCC = ""
.Subject = "This is the Subject line"
.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
 
P

pswanie

i would like to use the one where the sheet go in the body of the mail. but
i fail to see how to select more than one sheet. the examples that i see (and
i looked at the downloadeble workbooks) only add it as a new workbook. if i
uses kens thing i need to check and install that pdf on everymachine wich
could become a nightmare.

the perfect option would be to select more that one sheet and mail as
body.... or should i just have a next statement where it will mail 3 or 4
emails?
 
R

Ron de Bruin

Ok, I will post a example after dinner

--

Regards Ron de Bruin
http://www.rondebruin.nl/tips.htm


pswanie said:
i would like to use the one where the sheet go in the body of the mail. but
i fail to see how to select more than one sheet. the examples that i see (and
i looked at the downloadeble workbooks) only add it as a new workbook. if i
uses kens thing i need to check and install that pdf on everymachine wich
could become a nightmare.

the perfect option would be to select more that one sheet and mail as
body.... or should i just have a next statement where it will mail 3 or 4
emails?
 
R

Ron de Bruin

Before dinner


Try this for "Sheet1" and "Sheet2"

Sub Mail_Sheet_Outlook_Body()
' Don't forget to copy the function RangetoHTML in the module.
' Working in Office 2000-2007
Dim rng As Range
Dim rng2 As Range
Dim OutApp As Object
Dim OutMail As Object

With Application
.EnableEvents = False
.ScreenUpdating = False
End With

Set rng = Sheets("Sheet1").UsedRange
Set rng2 = Sheets("Sheet2").UsedRange

Set OutApp = CreateObject("Outlook.Application")
OutApp.Session.Logon
Set OutMail = OutApp.CreateItem(0)

On Error Resume Next
With OutMail
.To = "(e-mail address removed)"
.CC = ""
.BCC = ""
.Subject = "This is the Subject line"
.HTMLBody = RangetoHTML(rng) & "<br><br><br>" & RangetoHTML(rng2)
.display '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-2007
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
 
P

pswanie

works like a charm.
i adjusted it to send 5 sheets in total.

(some of them are landscape and now shows as portrait. any easy way to get
to stay landscape)


thanx a million
 

Ask a Question

Want to reply to this thread or ask your own question?

You'll need to choose a username for the site, which only take a couple of moments. After that, you can post your question and our members will help you out.

Ask a Question

Top