VBA to email last row in range

Mitch_Bird

New Member
Joined
Jan 4, 2015
Messages
4
Hi All,</SPAN>
(VBA learner :)</SPAN></SPAN> )</SPAN>
I am working on a VBA Code for emailing data from an excel spreadsheet. The below code will grab the data in a range of cells (A3:H50) and send email to whoever I have in cell H1 with subject in cell J1 – I have tested this code and it works fine but I do need help in making some alterations. </SPAN>
Instead of sending all data in the sheet, can I please get help with a code to grab last row of data with the headings and send that with a generic message above that data? The headings are from A3 to H3 and will never change but as there are multiple rows of data added in each day I will only require to send last row. Every time a new row of data is entered I will need and email sent, example - data entered in A35:H35 email to send with headings and Data for A35:H35 only, next row A36:H36 and repeat</SPAN>

Code:
Sub Send_Email2()
Dim rng As Range
Dim OutApp As Object
Dim OutMail As Object
Dim rngAttach As Range
    
    'Set range for file attachment, cell should contain the path and file name
    Sheets("Sheet1").Select
    With ActiveSheet
    Set rngAttach = .Range("H1")
    End With
Set rng = Nothing
' Only send the visible cells in the selection.
Set rng = Sheets("Sheet1").Range("A3:H50").SpecialCells(xlCellTypeVisible)
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)

With OutMail
    .To = ThisWorkbook.Sheets("Sheet1").Range("H1").Value
    'CC = ThisWorkbook.Sheets("Email").Range("").Value
    '.BCC = ThisWorkbook.Sheets("Email").Range("").Value
    .Subject = ThisWorkbook.Sheets("Sheet1").Range("J1").Value
    '.Display
    .HTMLBody = RangetoHTML(rng)
    ' In place of the following statement, you can use ".Display" to
    ' display the e-mail message.
    'strFileName = Dir(rngAttach.Value)
    '.Attachments.Add Replace(rngAttach.Value, "*.*", "") & strFileName
    '.Attachments.Add rngAttach.Value
    
    .send
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)
' By Ron de Bruin.
    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

Thanks in advance for your help.

Mitch
 

Excel Facts

What is the fastest way to copy a formula?
If A2:A50000 contain data. Enter a formula in B2. Select B2. Double-click the Fill Handle and Excel will shoot the formula down to B50000.
You could copy the range into a new workbook, save to a location, then attach that file to your e-mail instead of the current one.
 
Upvote 0
You could copy the range into a new workbook, save to a location, then attach that file to your e-mail instead of the current one.

Thanks for your response Dermie.
Not trying to attach a file, I would like to copy a range within my file</SPAN>
 
Upvote 0
Try this...

Code:
[color=darkblue]Sub[/color] Send_Email2()
    
    [color=darkblue]Dim[/color] rngAttach [color=darkblue]As[/color] Range
    
    [color=green]'Sheets("Sheet1").Select[/color]
    [color=green]'Header row 3 and last used row.[/color]
    [color=darkblue]With[/color] Sheets("Sheet1")
        [color=darkblue]Set[/color] rngAttach = .Range("A3:H3," & .Range("A" & Rows.Count).End(xlUp).Resize(, 8).Address)
    [color=darkblue]End[/color] [color=darkblue]With[/color]
    
    [color=darkblue]With[/color] Application
        .EnableEvents = [color=darkblue]False[/color]
        .ScreenUpdating = [color=darkblue]False[/color]
    [color=darkblue]End[/color] [color=darkblue]With[/color]
    
    [color=darkblue]With[/color] CreateObject("Outlook.Application").CreateItem(0)
        .To = ThisWorkbook.Sheets("Sheet1").Range("H1").Value
        .Subject = ThisWorkbook.Sheets("Sheet1").Range("J1").Value
        .HTMLBody = RangetoHTML(rngAttach)
        [color=green]' Send \ Display email[/color]
        .Send
        [color=green]'.Display[/color]
    [color=darkblue]End[/color] [color=darkblue]With[/color]
    
    [color=darkblue]With[/color] Application
        .EnableEvents = [color=darkblue]True[/color]
        .ScreenUpdating = [color=darkblue]True[/color]
    [color=darkblue]End[/color] [color=darkblue]With[/color]
    
[color=darkblue]End[/color] [color=darkblue]Sub[/color]

[color=darkblue]Function[/color] RangetoHTML(rng [color=darkblue]As[/color] Range)
    [color=green]' By Ron de Bruin.[/color]
    [color=darkblue]Dim[/color] fso    [color=darkblue]As[/color] [color=darkblue]Object[/color]
    [color=darkblue]Dim[/color] ts     [color=darkblue]As[/color] [color=darkblue]Object[/color]
    [color=darkblue]Dim[/color] TempFile [color=darkblue]As[/color] [color=darkblue]String[/color]
    [color=darkblue]Dim[/color] TempWB [color=darkblue]As[/color] Workbook
    TempFile = Environ$("temp") & "/" & Format(Now, "dd-mm-yy h-mm-ss") & ".htm"
    [color=green]'Copy the range and create a new workbook to past the data in[/color]
    rng.Copy
    [color=darkblue]Set[/color] TempWB = Workbooks.Add(1)
    [color=darkblue]With[/color] TempWB.Sheets(1)
        .Cells(1).PasteSpecial Paste:=8
        .Cells(1).PasteSpecial xlPasteValues, , [color=darkblue]False[/color], [color=darkblue]False[/color]
        .Cells(1).PasteSpecial xlPasteFormats, , [color=darkblue]False[/color], [color=darkblue]False[/color]
        .Cells(1).Select
        Application.CutCopyMode = False
        [color=darkblue]On[/color] [color=darkblue]Error[/color] [color=darkblue]Resume[/color] [color=darkblue]Next[/color]
        .DrawingObjects.Visible = [color=darkblue]True[/color]
        .DrawingObjects.Delete
        [color=darkblue]On[/color] [color=darkblue]Error[/color] [color=darkblue]GoTo[/color] 0
    [color=darkblue]End[/color] [color=darkblue]With[/color]
    [color=green]'Publish the sheet to a htm file[/color]
    [color=darkblue]With[/color] TempWB.PublishObjects.Add( _
         SourceType:=xlSourceRange, _
         Filename:=TempFile, _
         Sheet:=TempWB.Sheets(1).Name, _
         Source:=TempWB.Sheets(1).UsedRange.Address, _
         HtmlType:=xlHtmlStatic)
        .Publish (True)
    [color=darkblue]End[/color] [color=darkblue]With[/color]
    [color=green]'Read all data from the htm file into RangetoHTML[/color]
    [color=darkblue]Set[/color] fso = CreateObject("Scripting.FileSystemObject")
    [color=darkblue]Set[/color] ts = fso.GetFile(TempFile).OpenAsTextStream(1, -2)
    RangetoHTML = ts.ReadAll
    ts.Close
    RangetoHTML = Replace(RangetoHTML, "align=center x:publishsource=", _
                          "align=left x:publishsource=")
    [color=green]'Close TempWB[/color]
    TempWB.Close savechanges:=False
    [color=green]'Delete the htm file we used in this function[/color]
    Kill TempFile
    [color=darkblue]Set[/color] ts = [color=darkblue]Nothing[/color]
    [color=darkblue]Set[/color] fso = [color=darkblue]Nothing[/color]
    [color=darkblue]Set[/color] TempWB = [color=darkblue]Nothing[/color]
[color=darkblue]End[/color] [color=darkblue]Function[/color]

Mitch
 
Upvote 0

Forum statistics

Threads
1,215,227
Messages
6,123,738
Members
449,116
Latest member
alexlomt

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