Results 1 to 8 of 8

Export button

Threaded View

  1. #2
    Registered User
    Join Date
    03-17-2011
    Location
    Illinois
    MS-Off Ver
    2007-2010
    Posts
    22

    Re: Export button

    Try this code, assign it to a button, Review the code, and reset the name of your destination sheet (currently called RecordsOfTheNetherlands).. In this code, the data range is set to begin at A11. You want that to change to match your data set as well.
    Good luck.

    '<<<< Filter/Copy below the existing data of a existing worksheet(Sheet: RecordsOfTheNetherlands) >>>>>

    'This example will copy the filter results below the existing data on the destination sheet.
    'Note the sheet "RecordsOfTheNetherlands" must exist in your workbook.
    'This example will not copy the header row each time so when you manual add the worksheet
    '"RecordsOfTheNetherlands" to your workbook you must add the headers yourself on the first row.

    'I commented the Delete line in this tester
    'rng.EntireRow.Delete
    'Remove the ' before the code line if you want to delete the records you copied

    'Note: this example use the function LastRow in the ModReset module

    Sub Copy_With_AutoFilter2()
    'Note: This macro use the function LastRow
    'Important: The DestSh must exist
    Dim My_Range As Range
    Dim DestSh As Worksheet
    Dim CalcMode As Long
    Dim ViewMode As Long
    Dim FilterCriteria As String
    Dim CCount As Long
    Dim rng As Range

    'Set filter range on ActiveSheet: A11 is the top left cell of your filter range
    'and the header of the first column, D is the last column in the filter range.
    'You can also add the sheet name to the code like this :
    'Worksheets("Sheet1").Range("A11:D" & LastRow(Worksheets("Sheet1")))
    'No need that the sheet is active then when you run the macro when you use this.
    Set My_Range = Range("A11:D" & LastRow(ActiveSheet))
    My_Range.Parent.Select

    'Set the destination worksheet
    'Note: the sheet "RecordsOfTheNetherlands" must exist in your workbook.
    Set DestSh = Sheets("RecordsOfTheNetherlands")

    If ActiveWorkbook.ProtectStructure = True Or _
    My_Range.Parent.ProtectContents = True Then
    MsgBox "Sorry, not working when the workbook or worksheet is protected", _
    vbOKOnly, "Copy to new worksheet"
    Exit Sub
    End If

    'Change ScreenUpdating, Calculation, EnableEvents, ....
    With Application
    CalcMode = .Calculation
    .Calculation = xlCalculationManual
    .ScreenUpdating = False
    .EnableEvents = False
    End With
    ViewMode = ActiveWindow.View
    ActiveWindow.View = xlNormalView
    ActiveSheet.DisplayPageBreaks = False

    'Firstly, remove the AutoFilter
    My_Range.Parent.AutoFilterMode = False

    'Filter and set the filter field and the filter criteria :
    'This example filter on the first column in the range (change the field if needed)
    'In this case the range starts in A so Field 1 is column A, 2 = column B, ......
    'Use "<>Netherlands" as criteria if you want the opposite
    My_Range.AutoFilter Field:=1, Criteria1:="=Netherlands"

    'If you want to filter on a cell value you can use this, use "<>" for the opposite
    'This example uses the activecell value
    'My_Range.AutoFilter Field:=1, Criteria1:="=" & ActiveCell.Value

    'This will use the cell value from A2 as criteria
    'My_Range.AutoFilter Field:=1, Criteria1:="=" & Range("A2").Value

    ''If you want to filter on a Inputbox value use this
    'FilterCriteria = InputBox("What text do you want to filter on?", _
    ' "Enter the filter item.")
    'My_Range.AutoFilter Field:=1, Criteria1:="=" & FilterCriteria


    'Check if there are not more then 8192 areas(limit of areas that Excel can copy)
    CCount = 0
    On Error Resume Next
    CCount = My_Range.Columns(1).SpecialCells(xlCellTypeVisible).Areas(1).Cells.Count
    On Error GoTo 0
    If CCount = 0 Then
    MsgBox "There are more than 8192 areas:" _
    & vbNewLine & "It is not possible to copy the visible data." _
    & vbNewLine & "Tip: Sort your data before you use this macro.", _
    vbOKOnly, "Copy to worksheet"
    Else
    'Copy the visible data and use PasteSpecial to paste to the Destsh
    With My_Range.Parent.AutoFilter.Range
    On Error Resume Next
    ' Set rng to the visible cells in My_Range without the header row
    Set rng = .Offset(1, 0).Resize(.Rows.Count - 1, .Columns.Count) _
    .SpecialCells(xlCellTypeVisible)
    On Error GoTo 0
    If Not rng Is Nothing Then
    'Copy and paste the cells into DestSh below the existing data
    rng.Copy
    With DestSh.Range("A" & LastRow(DestSh) + 1)
    ' Paste:=8 will copy the columnwidth in Excel 2000 and higher
    ' Remove this line if you use Excel 97
    .PasteSpecial Paste:=8
    .PasteSpecial xlPasteValues
    .PasteSpecial xlPasteFormats
    Application.CutCopyMode = False
    End With
    'Delete the rows in the My_Range.Parent worksheet
    'rng.EntireRow.Delete
    End If
    End With
    End If

    'Close AutoFilter
    My_Range.Parent.AutoFilterMode = False

    'Restore ScreenUpdating, Calculation, EnableEvents, ....
    ActiveWindow.View = ViewMode
    Application.Goto DestSh.Range("A1")
    With Application
    .ScreenUpdating = True
    .EnableEvents = True
    .Calculation = CalcMode
    End With

    End Sub
    Last edited by Pete123abc; 05-20-2011 at 11:58 AM.

Thread Information

Users Browsing this Thread

There are currently 1 users browsing this thread. (0 members and 1 guests)

Bookmarks

Posting Permissions

  • You may not post new threads
  • You may not post replies
  • You may not post attachments
  • You may not edit your posts

Search Engine Friendly URLs by vBSEO 3.6.0 RC 1