Hi..
This should do most of what you want.. although i think you have got some of the values/column header names mixed up.. not sure.. either way.. you should be able to adjust any you need to..
Add this to your Sheet ( i added it to a Command Button)..
Private Sub CommandButton1_Click()
Dim LastRow As Long, j As Long
Dim OutApp As Object, OutMail As Object
Dim rng As Range
LastRow = Sheets("HUB outbound HTM daily report").Range("B" & Rows.Count).End(xlUp).Row
For j = 2 To LastRow
If Sheets("HUB outbound HTM daily report").Cells(j, 43) = 1 Then
GoTo 1
End If
Crit1 = Sheets("HUB outbound HTM daily report").Cells(j, 2)
Sheets("HUB outbound HTM daily report").Range("A1:AP1").AutoFilter Field:=2, Criteria1:=Crit1
'Populate the Email Grid
Sheets("SA").Cells(7, 2).Value = Sheets("HUB outbound HTM daily report").Cells(j, 2).Value
Sheets("SA").Cells(8, 2).Value = Sheets("HUB outbound HTM daily report").Cells(j, 4).Value
Sheets("SA").Cells(9, 2).Value = Sheets("HUB outbound HTM daily report").Cells(j, 5).Value
Sheets("SA").Cells(10, 2).Value = Sheets("HUB outbound HTM daily report").Cells(j, 3).Value
Sheets("SA").Cells(13, 2).Value = Sheets("HUB outbound HTM daily report").Cells(j, 17).Value
Sheets("SA").Cells(15, 2).Value = Sheets("HUB outbound HTM daily report").Cells(j, 19).Value
Sheets("SA").Cells(17, 2).Value = Sheets("HUB outbound HTM daily report").Cells(j, 26).Value
Sheets("SA").Cells(23, 2).Value = Sheets("HUB outbound HTM daily report").Cells(j, 25).Value
Sheets("SA").Cells(23, 4).Value = Sheets("HUB outbound HTM daily report").Cells(j, 30).Value
Sheets("SA").Cells(24, 2).Value = Sheets("HUB outbound HTM daily report").Cells(j, 27).Value
Sheets("SA").Cells(25, 2).Value = Sheets("HUB outbound HTM daily report").Cells(j, 28).Value
'Populate the info Cell (A2)
Sheets("SA").Cells(2, 1).Value = Sheets("HUB outbound HTM daily report").Cells(j, 3).Value
S1 = Sheets("SA").Cells(2, 1).Value
S2 = Sheets("SA").Cells(2, 12).Value
S3 = Sheets("SA").Cells(24, 2).Value
Application.ScreenUpdating = False
Set OutApp = CreateObject("Outlook.Application")
Set rng = Nothing
On Error Resume Next
Set rng = Sheets("SA").Range("A6:D26").SpecialCells(xlCellTypeVisible)
On Error GoTo cleanup
Set OutMail = OutApp.CreateItem(0)
On Error Resume Next
With OutMail
.To = Sheets("SA").Cells(2, 13).Value
.CC = Sheets("SA").Cells(2, 14).Value
.Subject = "Shipping advise for NL HUB outbound shipment " & S1 & " to " & S2 & " on " & S3
.HTMLBody = RangetoHTML(rng)
.Display 'Or use .Send
End With
On Error GoTo 0
Set OutMail = Nothing
cleanup:
Set OutApp = Nothing
Application.ScreenUpdating = True
If ActiveSheet.AutoFilterMode Then ActiveSheet.AutoFilterMode = False
Sheets("HUB outbound HTM daily report").Cells(j, 43).Value = 1
1
Next j
End Sub
And add this to a Module..
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
End Result:
screen.png
Bookmarks