+ Reply to Thread
Results 1 to 3 of 3

Insert a range from 2 or more different worksheets into the same email

Hybrid View

KAPearson Insert a range from 2 or more... 12-17-2014, 03:20 PM
Tinbendr Re: Insert a range from 2 or... 12-22-2014, 09:57 AM
KAPearson Re: Insert a range from 2 or... 12-22-2014, 07:05 PM
  1. #1
    Forum Contributor
    Join Date
    05-14-2012
    Location
    England
    MS-Off Ver
    Excel 2010/2013
    Posts
    100

    Insert a range from 2 or more different worksheets into the same email

    Hi, I found this code which allows you to select a range of cells from a worksheet and insert it into an email.
    I need to change it so I can add more ranges from other worksheets (in the same workbook) to the email before I send it.
    Can anyone help please?

    Sub Mail_Selection_Range_Outlook_Body()
    'For Tips see: http://www.rondebruin.nl/win/winmail/Outlook/tips.htm
    'Don't forget to copy the function RangetoHTML in the module.
    'Working in Excel 2000-2013
        Dim rng As Range
        Dim OutApp As Object
        Dim OutMail As Object
    
        Set rng = Nothing
        On Error Resume Next
        'Only the visible cells in the selection
        Set rng = Selection.SpecialCells(xlCellTypeVisible)
        'You can also use a fixed range if you want
        'Set rng = Sheets("YourSheet").Range("D4:D12").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 = "ron@debruin.nl"
            .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
    
    
    Function RangetoHTML(rng As Range)
    ' Changed by Ron de Bruin 28-Oct-2006
    ' Working in Office 2000-2013
        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

  2. #2
    Forum Expert Tinbendr's Avatar
    Join Date
    06-26-2012
    Location
    USA
    MS-Off Ver
    Office 2010
    Posts
    2,138

    Re: Insert a range from 2 or more different worksheets into the same email

    This seems to work.
    Sub Mail_Selection_Range_Outlook_Body()
    'For Tips see: http://www.rondebruin.nl/win/winmail/Outlook/tips.htm
    'Don't forget to copy the function RangetoHTML in the module.
    'Working in Excel 2000-2013
        Dim rng As Range
        Dim OutApp As Object
        Dim OutMail As Object
        Dim RngGrp As New Collection
    
        Set rng = Nothing
        On Error Resume Next
        'Only the visible cells in the selection
        'Set rng = Selection.SpecialCells(xlCellTypeVisible)
            
        'You can also use a fixed range if you want
        Set rng = Sheets("Sheet1").Range("D4:D12").SpecialCells(xlCellTypeVisible)
        RngGrp.Add rng, "Range1"
        
        Set rng = Sheets("Sheet2").Range("D4:D12").SpecialCells(xlCellTypeVisible)
        RngGrp.Add rng, "Range2"
        
        Set rng = Sheets("Sheet3").Range("D4:D12").SpecialCells(xlCellTypeVisible)
        RngGrp.Add rng, "Range3"
            
        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 = "ron@debruin.nl"
            .CC = ""
            .BCC = ""
            .Subject = "This is the Subject line"
            .HTMLBody = RangetoHTML(RngGrp)
            '.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
    
    
    Function RangetoHTML(ByRef RngGrp As Collection)
    ' Changed by Ron de Bruin 28-Oct-2006
    ' Working in Office 2000-2013
        Dim fso As Object
        Dim ts As Object
        Dim TempFile As String
        Dim TempWB As Workbook
        Dim A As Long
        Dim LastRow As Long
        
        LastRow = 1
        
        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
        
        Set TempWB = Workbooks.Add(1)
        With TempWB.Sheets(1)
            For A = 1 To RngGrp.Count
                Set rng = RngGrp(A)
                rng.Copy
                .Cells(LastRow, 1).PasteSpecial Paste:=8
                .Cells(LastRow, 1).PasteSpecial xlPasteValues, , False, False
                .Cells(LastRow, 1).PasteSpecial xlPasteFormats, , False, False
                .Cells(LastRow, 1).Select
                LastRow = .Cells(.Rows.Count, "A").End(xlUp).Row + 1
                Application.CutCopyMode = False
                On Error Resume Next
                .DrawingObjects.Visible = True
                .DrawingObjects.Delete
                On Error GoTo 0
            Next
        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
    David
    (*) Reputation points appreciated.

  3. #3
    Forum Contributor
    Join Date
    05-14-2012
    Location
    England
    MS-Off Ver
    Excel 2010/2013
    Posts
    100

    Re: Insert a range from 2 or more different worksheets into the same email

    Thanks very much for the reply. I'll be able to try it out next week now. It looks obvious now I see it but.... :-)

    Thanks again

+ Reply to Thread

Thread Information

Users Browsing this Thread

There are currently 1 users browsing this thread. (0 members and 1 guests)

Similar Threads

  1. Macro to Insert a row across a range of worksheets
    By hlpsom1 in forum Excel Programming / VBA / Macros
    Replies: 3
    Last Post: 04-16-2014, 01:06 PM
  2. How to send email from excel using VBA with Cell Range (Including Images) as Email Body
    By Novice_To_Excel in forum Excel Programming / VBA / Macros
    Replies: 1
    Last Post: 03-24-2014, 05:06 AM
  3. Macro to email range of data for each recipient from multiple worksheets
    By Ram84 in forum Excel Programming / VBA / Macros
    Replies: 0
    Last Post: 08-13-2013, 04:03 PM
  4. send selected range in email with default outlook email signature included
    By mdsickler in forum Excel Programming / VBA / Macros
    Replies: 0
    Last Post: 04-04-2013, 10:50 PM
  5. VBA Code to open email in Excel and insert a range and send
    By Bozo in forum Excel Programming / VBA / Macros
    Replies: 1
    Last Post: 12-09-2011, 04:22 PM

Bookmarks

Posting Permissions

  • You may not post new threads
  • You may not post replies
  • You may not post attachments
  • You may not edit your posts

Search Engine Friendly URLs by vBSEO 3.6.0 RC 1