Send mail with custom attachment active sheet (VBA)

ToseSenpai

New Member
Joined
Apr 18, 2021
Messages
29
Office Version
  1. 365
Platform
  1. Windows
Hi guys, good morning!
Can i ask your help?
I have this VBA code that, in a workbook, it allows me to send a mail with the active sheet (not entire workbook) in attachment.
The problem is: how can i build it for send the mail, not with all active sheet but only with a determinate range?
I dont want to include in the attachment some elements of active sheet that i will sent!

Thank you very much as always! :)

IMG_0008.jpg

VBA Code:
Sub Mail_activesheet()

'Working in Excel 2000-2016
    Dim rng As Range
    Dim OutApp As Object
    Dim OutMail As Object
    Dim StrBody, StrBody2 As String
    Dim Sourcewb As Workbook
    Dim Destwb As Workbook
    Dim TempFilePath As String
    Dim TempFileName As String
    Dim FileExtStr As String
    Dim FileFormatNum As Long
  
    With Application
        .EnableEvents = False
        .ScreenUpdating = False
    End With
  
    Set Sourcewb = ActiveWorkbook
    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 = ActiveSheet.Range("B2:F25").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
  
    'Copy the ActiveSheet to a new workbook
    ActiveSheet.copy
    Set Destwb = ActiveWorkbook

    'Determine the Excel version and file extension/format
    With Destwb
        If Val(Application.Version) < 12 Then
            'You use Excel 97-2003
            FileExtStr = ".xls": FileFormatNum = -4143
        Else
            'You use Excel 2007-2016
            Select Case Sourcewb.FileFormat
            Case 51: FileExtStr = ".xlsx": FileFormatNum = 51
            Case 52:
                If .HasVBProject Then
                    FileExtStr = ".xlsm": FileFormatNum = 52
                Else
                    FileExtStr = ".xlsx": FileFormatNum = 51
                End If
            Case 56: FileExtStr = ".xls": FileFormatNum = 56
            Case Else: FileExtStr = ".xlsb": FileFormatNum = 50
            End Select
        End If
    End With
  
  
    StrBody = "<font size=""3,5""face=""Calibri"" >" & _
          "TEXT" & "<br><br>" & _
              "TEXT" & "<br>" & _
              "TEXT"
            
    StrBody2 = "<font size=""3,5""face=""Calibri"" >" & _
          "<br><br><br><br>" & _
              "TEXT" & "<br>" & _
              "TEXT" & "<br>"
            
            

  
    'Save the new workbook/Mail it/Delete it
    TempFilePath = Environ$("temp") & "\"
    TempFileName = "R 1T " & Format(Now, "dd-mm-yy")

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

    With Destwb
        .SaveAs TempFilePath & TempFileName & FileExtStr, FileFormat:=FileFormatNum
        On Error Resume Next
    With OutMail
        .to = "MAIL"
        .CC = "MAIL"
        .BCC = ""
        .Subject = "TEXT" & Date
        .HTMLBody = StrBody & RangetoHTML(rng) & StrBody2
        .Attachments.Add Destwb.FullName
        .Display
    End With
        On Error GoTo 0
        .Close savechanges:=False
    End With

'Delete the file you have send
    Kill TempFilePath & TempFileName & FileExtStr
  
  
    Set OutMail = Nothing
    Set OutApp = Nothing

    With Application
        .ScreenUpdating = True
        .EnableEvents = True
    End With
  
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
 

Excel Facts

Does the VLOOKUP table have to be sorted?
No! when you are using an exact match, the VLOOKUP table can be in any order. Best-selling items at the top is actually the best.
Try this:

Replace this lines:
VBA Code:
    'Copy the ActiveSheet to a new workbook
    ActiveSheet.copy
    Set Destwb = ActiveWorkbook

For this:
VBA Code:
    'Copy the rng to a new workbook
    Set Destwb = Workbooks.Add(xlWBATWorksheet)
    rng.Copy
    With Destwb.Sheets(1).Range(rng.Cells(1).Address)
      .PasteSpecial xlPasteAll
      .PasteSpecial xlPasteColumnWidths
    End With
 
Upvote 0
Solution
Try this:

Replace this lines:
VBA Code:
    'Copy the ActiveSheet to a new workbook
    ActiveSheet.copy
    Set Destwb = ActiveWorkbook

For this:
VBA Code:
    'Copy the rng to a new workbook
    Set Destwb = Workbooks.Add(xlWBATWorksheet)
    rng.Copy
    With Destwb.Sheets(1).Range(rng.Cells(1).Address)
      .PasteSpecial xlPasteAll
      .PasteSpecial xlPasteColumnWidths
    End With
It works perfecly!!! Thank you very much :love:
 
Upvote 0
I'm glad to help you. Thanks for the feedback.
 
Upvote 0

Forum statistics

Threads
1,224,816
Messages
6,181,143
Members
453,021
Latest member
Justyna P

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