Consulting

Results 1 to 10 of 10

Thread: Email Range in Body of Email - Not pasting the data

  1. #1

    Email Range in Body of Email - Not pasting the data

    Hi folks, not been on in a while as all has been good on the excel front. Sadly I am having an off day and cannot for the life of me get The following to work.



    When I click the button assigned to the code - it displays the new email with recipients and subject - however it will not paste in the excel range or teh textstring. Any Suggestions would be welcome

    I know it will be something silly but for the life of me - I am stumped today

    Sub Mail_Selection_Range_Outlook_Body()
        Dim rng As Range
        Dim OutApp As Object
        Dim OutMail As Object
        Dim StrBody As String
        
        StrBody = "Afternoon All," & "<br>" & "<br>" & _
        "Please see below for the latest Daily Update." & "<br><br>"
    
        Set rng = Nothing
        On Error Resume Next
        Set rng = Sheets("Output").Range("B4:W56").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 = "***x"
            .CC = ""
            .BCC = ""
            .Subject = "Daily Update ***X"
            .HTMLBody = StrBody & RangetoHTML(rng)
            .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)
        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"
    
        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
    
        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
     
        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
    Administrator
    VP-Knowledge Base
    VBAX Grand Master mdmackillop's Avatar
    Joined
    May 2004
    Location
    Scotland
    Posts
    14,489
    Location
    Your code works for me. Got data in Output?
    MVP (Excel 2008-2010)

    Post a workbook with sample data and layout if you want a quicker solution.


    To help indent your macros try Smart Indent

    Please remember to mark threads 'Solved'

  3. #3
    Hahah, nope, it shows a completely blank email. Has all the recipients and subjects in it but no data in the email at all. Is there an outlook setting I may be missing in Outlook?

  4. #4
    Administrator
    VP-Knowledge Base VBAX Grand Master mdmackillop's Avatar
    Joined
    May 2004
    Location
    Scotland
    Posts
    14,489
    Location
    Does
    .HTMLBody = StrBody
    insert the value?
    MVP (Excel 2008-2010)

    Post a workbook with sample data and layout if you want a quicker solution.


    To help indent your macros try Smart Indent

    Please remember to mark threads 'Solved'

  5. #5
    Administrator
    VP-Knowledge Base VBAX Grand Master mdmackillop's Avatar
    Joined
    May 2004
    Location
    Scotland
    Posts
    14,489
    Location
    or check that the data is there
    ActiveWorkbook.FollowHyperlink TempFile
        Stop
        Set fso = CreateObject("Scripting.FileSystemObject")
    MVP (Excel 2008-2010)

    Post a workbook with sample data and layout if you want a quicker solution.


    To help indent your macros try Smart Indent

    Please remember to mark threads 'Solved'

  6. #6
    Quote Originally Posted by mdmackillop View Post
    Does
    .HTMLBody = StrBody
    insert the value?
    It doesn't input the text string either. All I get is a totally blank email, with the recipients and subject.

    As a side note, it works if I unhide some columns that are hidden.

  7. #7
    VBAX Guru Kenneth Hobs's Avatar
    Joined
    Nov 2005
    Location
    Tecumseh, OK
    Posts
    4,956
    Location
    When debugging, comment out OnError lines. Step through code with F8.

    Is your sheet protected? If so, let the code make changes. e.g.
    Sheeet1.Protect "yourPasswordHereOrBlank", UserInterfaceOnly:=True

  8. #8
    Sheets are not protected. It only fails if columns are hidden. If I unhide all columns, then it works fine.

  9. #9
    Yeeeeha. I got it to work by electing its own range in the temp book and deleting what I didnt want in the temp workbook - instead of hiding columns etc.

    Sub Mail_Selection_Range_Outlook_Body()
        Dim rng As Range
        Dim OutApp As Object
        Dim OutMail As Object
        Dim StrBody As String
        
        StrBody = "Afternoon All," & "<br>" & "<br>" & _
        "Please see below for the latest Daily Update." & "<br><br>"
    
        Set rng = Nothing
        On Error Resume Next
        Set rng = Sheets("Output").Range("B4:W56").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 = "***x"
            .CC = ""
            .BCC = ""
            .Subject = "Daily Update ***X"
            .HTMLBody = StrBody & RangetoHTML(rng)
            .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)
        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"
    
        Range("B2:W56").Select
        Selection.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
        
    With TempWB.Sheets(1)
            Columns("P:P").Delete Shift:=xlToLeft
            Columns("R:R").Delete Shift:=xlToLeft
            On Error GoTo 0
        End With
        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
        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

  10. #10
    VBAX Guru Kenneth Hobs's Avatar
    Joined
    Nov 2005
    Location
    Tecumseh, OK
    Posts
    4,956
    Location
    If that is the case, then record a macro to unhide/hide if you don't know the syntax.

Posting Permissions

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