Excel VBA Union Ranges

mrsushi

Board Regular
Joined
Nov 18, 2006
Messages
180
Office Version
  1. 2010
Trying to copy cells A2:C6 & Z2:AA6 from the same sheet so the data appears in the body of outlook email. However, this isn't working

Any ideas please?
Code:
Sub Mail_Selection_Range_Outlook_Body()

Dim rng As Range
Dim OutApp As Object
Dim OutMail As Object
Datestamp = Sheets("sheet1).Range("a1")

Columns("A:L").Select
Columns("A:L").EntireColumn.AutoFit
Columns("A:L").EntireColumn.HorizontalAlignment = xlCenter

ActiveWorkbook.Save

Set rng = Nothing
' Only send the visible cells in the selection.

Set rng = Union(Range("A2:C6").Range("Z2:AA6")).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 = ""
.CC = ""
.BCC = ""
.Subject = ""
.HTMLBODY =
RangetoHTML(rng)
.Attachments.Add Application.ActiveWorkbook.FullName
.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
 
Last edited by a moderator:

Excel Facts

How to change case of text in Excel?
Use =UPPER() for upper case, =LOWER() for lower case, and =PROPER() for proper case. PROPER won't capitalize second c in Mccartney
Haven't looked at all your code, but for the Union line, try replacing that line with this:
VBA Code:
On Error Resume Next
Set Rng = Union(Range("A2:C6"), Range("Z2:AA6")).SpecialCells(xlCellTypeVisible)
On Error GoTo 0
If Rng Is Nothing Then
'rest of code
 
Upvote 0
Thanks Joe, That worked at treat. I can see my mistake was the prefix to Range("z2:AA6")) utilised a dot(.), where I should have used a comma
 
Upvote 0
Thanks Joe, That worked at treat. I can see my mistake was the prefix to Range("z2:AA6")) utilised a dot(.), where I should have used a comma
You are welcome - thanks for the reply.
 
Upvote 0
You are welcome - thanks for the reply.

Good afternoon joe,

Looking at the code which you provided me, its possible to make this code more dynamic? The data will always start from row 2, but in terms of how many rows, this will vary so the fix range may always need tweaking if data exceeds row 6. How can this be amended if we incorporate the code lastRow = Range("A" & Rows.Count).End(xlUp).Row?

Many thanks
M
 
Upvote 0
Good afternoon joe,

Looking at the code which you provided me, its possible to make this code more dynamic? The data will always start from row 2, but in terms of how many rows, this will vary so the fix range may always need tweaking if data exceeds row 6. How can this be amended if we incorporate the code lastRow = Range("A" & Rows.Count).End(xlUp).Row?

Many thanks
M
Assuming you have defined the variable lastRow as shown in bold above, and that A2 and Z2 are fixed, change this line:

Set Rng = Union(Range("A2:C6"), Range("Z2:AA6")).SpecialCells(xlCellTypeVisible)
to this:
Set Rng = Union(Range("A2:C" & lastRow), Range("Z2:AA" & lastRow)).SpecialCells(xlCellTypeVisible)
 
Upvote 0
Assuming you have defined the variable lastRow as shown in bold above, and that A2 and Z2 are fixed, change this line:

Set Rng = Union(Range("A2:C6"), Range("Z2:AA6")).SpecialCells(xlCellTypeVisible)
to this:
Set Rng = Union(Range("A2:C" & lastRow), Range("Z2:AA" & lastRow)).SpecialCells(xlCellTypeVisible)

Thanks Joe. That's worked
 
Upvote 0

Forum statistics

Threads
1,214,615
Messages
6,120,538
Members
448,970
Latest member
kennimack

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