Excel VBA to Outlook Select Range lastRow

promo1313

New Member
Joined
Sep 4, 2019
Messages
13
Hey guys,

I need for the code to stop copying at the lat line with data, but cant figure out how to code it. Pretty sure i need to use lastRow, but Im not sure how to replace the range.

VBA Code:
Sub Main()
'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-2016
    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("Sheet1").Range("A1:F250").SpecialCells(xlCellTypeVisible)
    'Set lastRow
    'Sheets("Sheet1").Range("A1:F250").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 = Sheets("Contacts").Range("F4").Value
        .CC = "isaac.santos@expeditors.com,sju-ivm@expeditors.com"
        .BCC = ""
        .Subject = "Expeditors Statement"
        .HTMLBody = RangetoHTML(rng)
        .Display   '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)

    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

Enter current date or time
Ctrl+: enters current time. Ctrl+; enters current date. Use Ctrl+: Ctrl+; Enter for current date & time.
Replace this line:
VBA Code:
Set rng = Sheets("Sheet1").Range("A1:F250").SpecialCells(xlCellTypeVisible)

With this:
VBA Code:
  Dim lastRow As Long
  lastRow = Sheets("Sheet1").Range("A" & Rows.Count).End(xlUp).Row
    Set rng = Sheets("Sheet1").Range("A1:F" & lastRow).SpecialCells(xlCellTypeVisible)
 
Upvote 0
Replace this line:
VBA Code:
Set rng = Sheets("Sheet1").Range("A1:F250").SpecialCells(xlCellTypeVisible)

With this:
VBA Code:
  Dim lastRow As Long
  lastRow = Sheets("Sheet1").Range("A" & Rows.Count).End(xlUp).Row
    Set rng = Sheets("Sheet1").Range("A1:F" & lastRow).SpecialCells(xlCellTypeVisible)
Thanks Dante.

But it keeps copying the blank rows below the data. Do you think its maybe because those rows have formulas in them?
 
Upvote 0
Use this

VBA Code:
  Dim lastRow As Long
 LastRow = Sheets("Sheet1").Columns(1).Find("*", , xlValues, , xlByRows, xlPrevious).Row
    Set rng = Sheets("Sheet1").Range("A1:F" & lastRow).SpecialCells(xlCellTypeVisible)
 
Upvote 0

Forum statistics

Threads
1,223,230
Messages
6,170,883
Members
452,364
Latest member
springate

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