Copy Two Visible Ranges (From Two Sheets) To A New Workbook (AlsoWith Two Sheets)

S

septhemis

Hello,

From an existing source workbook, I need to copy two specific sheets
(where both sheets now contain autofiltered rows and hidden columns)
and paste them into a new destination workbook also containing two
worksheets (but these destination worksheets should not contain those
autofiltered rows and hidden columns). Eventually I need to email
that new destination workbook.

To acheive this, I am using Ron De Bruin's macro code for "Mail Range
or Selection" (http://www.rondebruin.nl/mail/folder2/mail4.htm).

Be mindful that I need the new destination workbook to only have those
two sheets with just the visible data with all formatting intact (just
eliminate invisible data and NOT to have those filtered rows and
hidden columns). If this was not the case, I could have simply used
an array statement that Ron De Bruin uses in one of his other email
macro examples.
..Sheets(Array("Sheet1", "Sheet3")).Copy

With that being said, I have already modified Ron's code but it only
works for one sheet. I need this to happen to another sheet as well.
Also I would like to hard code both these sheet names in the macro
with their codenames, if possible. Any alternative methods which
could be effective and efficient, are also welcome.

Any help will be greatly appreciated. Thanks in advance. Here is the
modified code.

Set Source = Nothing
On Error Resume Next
Set Source = ActiveSheet.UsedRange.SpecialCells(xlCellTypeVisible)
On Error GoTo 0

If Source Is Nothing Then
MsgBox "The source is not a range or the sheet is protected, "
& _
"please correct and try again.", vbOKOnly
Exit Sub
End If

Set wb = ActiveWorkbook
Set Dest = Workbooks.Add(xlWBATWorksheet)
Source.Copy
With Dest.Sheets(1)
.Cells(1).PasteSpecial Paste:=8
.Cells(1).PasteSpecial Paste:=xlPasteValues
.Cells(1).PasteSpecial Paste:=xlPasteFormats
.Cells(1).Select
'Assigning source workbook's sheet name to the copied sheet
in this new workbook
.Name = wb.Sheets(1).Name
Application.CutCopyMode = False
End With
 
R

Ron de Bruin

Hi

You have two options

1: create a PDF (code is on my site for 2007)
2 create a loop that create a new workbook
Add a new sheet and copy the visible data to this sheet.
Do this for every sheet in the loop

No time now but I will make a example for you this evening
if you want.
Let me know if you need more help
 
R

Ron de Bruin

Hi

Try this one for "sheet1" and "Sheet3"

Sub Mail_Range_test()
'Working in 2000-2007
Dim Source As Range
Dim Dest As Workbook
Dim wb As Workbook
Dim TempFilePath As String
Dim TempFileName As String
Dim FileExtStr As String
Dim FileFormatNum As Long
Dim OutApp As Object
Dim OutMail As Object

With Application
.ScreenUpdating = False
.EnableEvents = False
End With

Set wb = ActiveWorkbook
Set Dest = Workbooks.Add(xlWBATWorksheet)
Dest.Worksheets.Add after:=Worksheets(1)

Set Source = Nothing
On Error Resume Next
Set Source = wb.Sheets("Sheet1").UsedRange.SpecialCells(xlCellTypeVisible)
On Error GoTo 0

Source.Copy
With Dest.Sheets(1)
.Select
.Cells(1).PasteSpecial Paste:=8
.Cells(1).PasteSpecial Paste:=xlPasteValues
.Cells(1).PasteSpecial Paste:=xlPasteFormats
.Cells(1).Select
Application.CutCopyMode = False
End With

Set Source = Nothing
On Error Resume Next
Set Source = wb.Sheets("Sheet3").UsedRange.SpecialCells(xlCellTypeVisible)
On Error GoTo 0

Source.Copy
With Dest.Sheets(2)
.Select
.Cells(1).PasteSpecial Paste:=8
.Cells(1).PasteSpecial Paste:=xlPasteValues
.Cells(1).PasteSpecial Paste:=xlPasteFormats
.Cells(1).Select
Application.CutCopyMode = False
End With

TempFilePath = Environ$("temp") & "\"
TempFileName = "Selection of " & wb.Name & " " _
& Format(Now, "dd-mmm-yy h-mm-ss")

If Val(Application.Version) < 12 Then
'You use Excel 2000-2003
FileExtStr = ".xls": FileFormatNum = -4143
Else
'You use Excel 2007
FileExtStr = ".xlsx": FileFormatNum = 51
End If

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

With Dest
.SaveAs TempFilePath & TempFileName & FileExtStr, _
FileFormat:=FileFormatNum
On Error Resume Next
With OutMail
.To = "(e-mail address removed)"
.CC = ""
.BCC = ""
.Subject = "This is the Subject line"
.Body = "Hi there"
.Attachments.Add Dest.FullName
'You can add other files also like this
'.Attachments.Add ("C:\test.txt")
.Send 'or use .Display
End With
On Error GoTo 0
.Close SaveChanges:=False
End With

Kill TempFilePath & TempFileName & FileExtStr

Set OutMail = Nothing
Set OutApp = Nothing

With Application
.ScreenUpdating = True
.EnableEvents = True
End With
End Sub
 
D

DP

Ron, it works great.

Thanks a bunch.

Hi

Try this one for "sheet1" and "Sheet3"

Sub Mail_Range_test()
'Working in 2000-2007
    Dim Source As Range
    Dim Dest As Workbook
    Dim wb As Workbook
    Dim TempFilePath As String
    Dim TempFileName As String
    Dim FileExtStr As String
    Dim FileFormatNum As Long
    Dim OutApp As Object
    Dim OutMail As Object

    With Application
        .ScreenUpdating = False
        .EnableEvents = False
    End With

    Set wb = ActiveWorkbook
    Set Dest = Workbooks.Add(xlWBATWorksheet)
    Dest.Worksheets.Add after:=Worksheets(1)

    Set Source = Nothing
    On Error Resume Next
    Set Source = wb.Sheets("Sheet1").UsedRange.SpecialCells(xlCellTypeVisible)
    On Error GoTo 0

    Source.Copy
    With Dest.Sheets(1)
        .Select
        .Cells(1).PasteSpecial Paste:=8
        .Cells(1).PasteSpecial Paste:=xlPasteValues
        .Cells(1).PasteSpecial Paste:=xlPasteFormats
        .Cells(1).Select
        Application.CutCopyMode = False
    End With

    Set Source = Nothing
    On Error Resume Next
    Set Source = wb.Sheets("Sheet3").UsedRange.SpecialCells(xlCellTypeVisible)
    On Error GoTo 0

    Source.Copy
    With Dest.Sheets(2)
        .Select
        .Cells(1).PasteSpecial Paste:=8
        .Cells(1).PasteSpecial Paste:=xlPasteValues
        .Cells(1).PasteSpecial Paste:=xlPasteFormats
        .Cells(1).Select
        Application.CutCopyMode = False
    End With

    TempFilePath = Environ$("temp") & "\"
    TempFileName = "Selection of " & wb.Name & " " _
                 & Format(Now, "dd-mmm-yy h-mm-ss")

    If Val(Application.Version) < 12 Then
        'You use Excel 2000-2003
        FileExtStr = ".xls": FileFormatNum = -4143
    Else
        'You use Excel 2007
        FileExtStr = ".xlsx": FileFormatNum = 51
    End If

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

    With Dest
        .SaveAs TempFilePath & TempFileName & FileExtStr, _
                FileFormat:=FileFormatNum
        On Error Resume Next
        With OutMail
            .To = "(e-mail address removed)"
            .CC = ""
            .BCC = ""
            .Subject = "This is the Subject line"
            .Body = "Hi there"
            .Attachments.Add Dest.FullName
            'You can add other files also like this
            '.Attachments.Add ("C:\test.txt")
            .Send   'or use .Display
        End With
        On Error GoTo 0
        .Close SaveChanges:=False
    End With

    Kill TempFilePath & TempFileName & FileExtStr

    Set OutMail = Nothing
    Set OutApp = Nothing

    With Application
        .ScreenUpdating = True
        .EnableEvents = True
    End With
End Sub

--

Regards Ron de Bruinhttp://www.rondebruin.nl/tips.htm













- Show quoted text -
 

Ask a Question

Want to reply to this thread or ask your own question?

You'll need to choose a username for the site, which only take a couple of moments. After that, you can post your question and our members will help you out.

Ask a Question

Top