Following macro works fine in newer version of excel, however get compile error in 2010

1nk3d

Board Regular
Joined
May 31, 2016
Messages
51
The below macro triggers a compile error in excel 2010. I am not great with macros, so any insight would be appreciate. The macro copies part of a workbook and pastes it as a picture in the body of an email and sends it.
Code:
Sub FRIMail()
Dim r As Range
Set r = Worksheets("Fri").Range("A1:M69")
r.Copy
Dim OutApp As Object
    Dim outMail As Object
    Set OutApp = CreateObject("Outlook.Application")
    Set outMail = OutApp.CreateItem(0)
On Error Resume Next
    With outMail
    .display
    .HTMLBody = activemailmessage.HTMLBody
        .To = Worksheets("Distribution").Range("N13").Value
        .CC = ""
        .BCC = ""
        .Subject = "REPORT"
        .body = "Report was run on: " & Now

Dim wordDoc As Word.document
Set wordDoc = outMail.GetInspector.WordEditor

wordDoc.Range.PasteAndFormat wdChartPicture
outMail.send
End With
End Sub
 
I just realized that it was cutting those cells out of the worksheet completely. Is there a way to just paste them to another worksheet (Email) and do the cutting from there? I can't cut out of the original as those cells that are hidden have the formulas the roll up and the other sheets calculate based on them. Pretty much I have 6 daily sheets for each day of the week, so the hidden cells for Saturday, are referenced on Monday, and Mondays on Tuesday etc... Aside from cutting, it worked good.
 
Upvote 0

Excel Facts

Why does 9 mean SUM in SUBTOTAL?
It is because Sum is the 9th alphabetically in Average, Count, CountA, Max, Min, Product, StDev.S, StDev.P, Sum, VAR.S, VAR.P.
.
Here is an edit to the original macros. This macro copies from Sheet 1, Columns A,B,D,F ... pastes these columns to a newly created sheet named "Email Temp" ... processes
the data as before into the body of an email .... then deletes the temporary sheet "Email Temp".

You can edit the sheet names and ranges as required for your needs .

Code:
Option Explicit


Sub test()


Dim wsh As Worksheet
Set wsh = Worksheets.Add(Before:=Worksheets("Sheet1"))
            wsh.Name = "Email Temp"
Application.ScreenUpdating = False
Sheets("Sheet1").Activate
Sheets("Sheet1").Range("A:A, B:B, D:D,F:F").Select
Selection.Copy
Sheets("Email Temp").Range("A1").PasteSpecial
Sheets("Sheet1").Range("A1").Select
Application.CutCopyMode = False
Application.ScreenUpdating = True
   
CopyRows


End Sub




Sub CopyRows()
Dim i As Integer
Dim ws1 As Worksheet: Set ws1 = ThisWorkbook.Sheets("Email Temp")
    ws1.Range("A1:F20").Copy
    Mail_Selection_Range_Outlook_Body
End Sub




Sub Mail_Selection_Range_Outlook_Body()
Dim rng As Range
Dim OutApp As Object
Dim OutMail As Object
Dim lEndRow
Dim Value As String
Set rng = Nothing
' Only send the visible cells in the selection.
Set rng = Sheets("Email Temp").Range("A1:F20")
If rng Is Nothing Then
    MsgBox "An unknown error has occurred. "
    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 = "Your email address here in quotes"
    .CC = ""
    .BCC = ""
    .Subject = "Trigger Point for Cars On Hand"
    .HTMLBody = "Text above Excel cells" & "" & RangetoHTML(rng) & "" & "Text below Excel cells."
    ' 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
Application.DisplayAlerts = False
Sheets("Email Temp").Delete
Application.DisplayAlerts = True
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
 
Upvote 0
How can it be pasted as an image, or is that not possible?

If not as an image how can we paste it with the row lines and such?
 
Upvote 0
.
There are prettier ways of doing this but this works (anyone feel free to step in and edit this macro) :

Code:
Option Explicit


Sub test()


Dim wsh As Worksheet
Set wsh = Worksheets.Add(Before:=Worksheets("Sheet1"))
            wsh.Name = "Email Temp"
Application.ScreenUpdating = False
Sheets("Sheet1").Activate
Sheets("Sheet1").Range("A:A, B:B, D:D,F:F").Select
Selection.Copy
Sheets("Email Temp").Range("A1").PasteSpecial


Macro1
Sheets("Sheet1").Activate
Sheets("Sheet1").Range("A1").Select
Application.CutCopyMode = False
Application.ScreenUpdating = True
   
CopyRows
End Sub




Sub CopyRows()
Dim i As Integer
Dim ws1 As Worksheet: Set ws1 = ThisWorkbook.Sheets("Email Temp")
    ws1.Range("A1:F21").Copy
    Mail_Selection_Range_Outlook_Body
End Sub








Sub Mail_Selection_Range_Outlook_Body()
Dim rng As Range
Dim OutApp As Object
Dim OutMail As Object
Dim lEndRow
Dim Value As String
Set rng = Nothing
' Only send the visible cells in the selection.
Set rng = Sheets("Email Temp").Range("A1:F21")
If rng Is Nothing Then
    MsgBox "An unknown error has occurred. "
    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 = "Your email address here in quotes"
    .CC = ""
    .BCC = ""
    .Subject = "Trigger Point for Cars On Hand"
    .HTMLBody = "Text above Excel cells" & vbCrLf & RangetoHTML(rng) & vbCrLf & "Text below Excel cells."
    ' 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
Application.DisplayAlerts = False
Sheets("Email Temp").Delete
Application.DisplayAlerts = True
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


Sub Macro1()


Sheets("Email Temp").Select
    Range("A1:D20").Select
    With Selection.Borders(xlEdgeLeft)
        .LineStyle = xlContinuous
        .ColorIndex = xlAutomatic
        .Weight = xlMedium
    End With
    With Selection.Borders(xlEdgeTop)
        .LineStyle = xlContinuous
        .ColorIndex = xlAutomatic
        .Weight = xlMedium
    End With
    With Selection.Borders(xlEdgeBottom)
        .LineStyle = xlContinuous
        .ColorIndex = xlAutomatic
        .Weight = xlMedium
    End With
    With Selection.Borders(xlEdgeRight)
        .LineStyle = xlContinuous
        .ColorIndex = xlAutomatic
        .Weight = xlMedium
    End With
    With Selection.Borders(xlInsideVertical)
        .LineStyle = xlContinuous
        .ColorIndex = xlAutomatic
        .Weight = xlMedium
    End With
    With Selection.Borders(xlInsideHorizontal)
        .LineStyle = xlContinuous
        .ColorIndex = xlAutomatic
        .Weight = xlMedium
    End With
End Sub
 
Upvote 0

Forum statistics

Threads
1,223,911
Messages
6,175,327
Members
452,635
Latest member
laura12345

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