Back to jkp-ads.com |
Ron de Bruin
|
Ron de Bruin decided to remove all Windows Excel content from his website for personal reasons. If you want to know why, head over to rondebruin.nl.
Luckily, Ron was kind enough to allow me to publish all of his Excel content here.
Most of these pages are slightly outdated and may contain links that don 't work. Please inform me if you find such an error and I'll try to fix it.
Kind regards
Jan Karel Pieterse
For more examples and a example workbook with the code below go to :
Copy records with the same value in a column to a new
sheet or workbook
The range for the code example below looks like this
Column A
: Header in A1 = Country, A2:A? = Country names
Column B
: Header in B1 = Name, B2:B? = Names
Column C : Header
in C1 = Gender, C2:C? = F or M
Column D : Header in D1 =
Birthday, D2:D? = Dates
The macro will add a new worksheet to your
workbook and will copy every record with Netherlands in the first column to
this new sheet (the code will ask you for a sheet name).
Check if the
information in these lines in the macro is correct before you run the macro
1: Set filter range on ActiveSheet: A1
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("A1: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("A1:D" & LastRow(ActiveSheet))
2: 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"
3:Important:This
macro call a function named LastRow
You find this function below the
macro, copy this function together with the macro in a standard module
In the code you see four filter examples that you can use, we use
example 1 in this macro and I commented the other 3 examples in the code.
1: Criteria in the code (=Netherlands, see the tips below
the macro)
2: Filter on ActiveCell value
3:
Filter on Range value (D1 in this example)
4: Filter on
InputBox value
Sub Copy_With_AutoFilter1() 'Note: This macro use the function LastRow Dim My_Range As Range Dim CalcMode As Long Dim ViewMode As Long Dim FilterCriteria As String Dim CCount As Long Dim WSNew As Worksheet Dim sheetName As String Dim rng As Range 'Set filter range on ActiveSheet: A1 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("A1: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("A1:D" & LastRow(ActiveSheet)) My_Range.Parent.Select 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 'Add a new Worksheet Set WSNew = Worksheets.Add(After:=Sheets(ActiveSheet.Index)) 'Ask for the Worksheet name sheetName = InputBox("What is the name of the new worksheet?", _ "Name the New Sheet") On Error Resume Next WSNew.Name = sheetName If Err.Number > 0 Then MsgBox "Change the name of sheet : " & WSNew.Name & _ " manually after the macro is ready. The sheet name" & _ " you fill in already exists or you use characters" & _ " that are not allowed in a sheet name." Err.Clear End If On Error GoTo 0 'Copy/paste the visible data to the new worksheet My_Range.Parent.AutoFilter.Range.Copy With WSNew.Range("A1") ' 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 .Select End With ' If you want to delete the rows that you copy, also use this ' With My_Range.Parent.AutoFilter.Range ' On Error Resume Next ' Set rng = .Offset(1, 0).Resize(.Rows.Count - 1, .Columns.Count) _ ' .SpecialCells(xlCellTypeVisible) ' On Error GoTo 0 ' If Not rng Is Nothing Then rng.EntireRow.Delete ' End With End If 'Close AutoFilter My_Range.Parent.AutoFilterMode = False 'Restore ScreenUpdating, Calculation, EnableEvents, .... My_Range.Parent.Select ActiveWindow.View = ViewMode If Not WSNew Is Nothing Then WSNew.Select With Application .ScreenUpdating = True .EnableEvents = True .Calculation = CalcMode End With End Sub Function LastRow(sh As Worksheet) On Error Resume Next LastRow = sh.Cells.Find(What:="*", _ After:=sh.Range("A1"), _ Lookat:=xlPart, _ LookIn:=xlValues, _ SearchOrder:=xlByRows, _ SearchDirection:=xlPrevious, _ MatchCase:=False).Row On Error GoTo 0 End Function
In the example I filter on the first column for the Netherlands
My_Range.AutoFilter Field:=1,
Criteria1:="=Netherlands"
But you can also repeat the line for other fields.
This will
filter all males from the Netherlands (column A and C in my example)
My_Range.AutoFilter Field:=1,
Criteria1:="=Netherlands"
My_Range.AutoFilter Field:=3, Criteria1:="=M"
Use this to filter for all males from the Netherlands and the USA
(column A and C in my example)
I use two criteria in field 1 (2 is the
maximum for AutoFilter in one field)
My_Range.AutoFilter Field:=1, Criteria1:="=Netherlands", Operator:=xlOr,
Criteria2:="=USA"
My_Range.AutoFilter Field:=3, Criteria1:="=M"
Use this to filter for all males born between 23 Feb 1947 and 7 May 1988
from the Netherlands and USA (column A, C and D in my example). I use two
criteria in field 1 and 4 (2 is the maximum for AutoFilter)
My_Range.AutoFilter Field:=1,
Criteria1:="=Netherlands", Operator:=xlOr, Criteria2:="=USA"
My_Range.AutoFilter Field:=3, Criteria1:="=F"
My_Range.AutoFilter
Field:=4, Criteria1:=">=02/23/1947", _
Operator:=xlAnd,
Criteria2:="<=05/07/1988"
Important: Use
always the US mm/dd/yyyy format if you filter Dates.
Note:
You only have the use the mm/dd/yyyy format in the code, no problem if the
format in the worksheet is different.
Tip: Use wildcards
If you want to copy every record that has a value in the first column that starts with Netherlands you can use Criteria1:="=Netherlands*" Or if Netherlands is a part of the string Criteria1:="=*Netherlands*" You can also use the wildcard ? for one character.
Activate AutoFilter:
Select a cell in your data
range and use Data>Filter>AutoFilter to activate AutoFilter. In Excel
2007-2013 click on the Data tab on the ribbon and then on Filter in the Sort
& Filter group. Note: If there are empty rows or columns in
your data range select the whole range first.
Tip: The
shortcut for every English Excel version to turn on AutoFilter is
Alt d f f
In each header cell a dropdown will appear next to
your field name. Click on the dropdown in the Country field and choose
Netherlands.
How to Copy the filter result to a new
worksheet:
1) Select the whole data range
or if you not have empty rows/columns in the range. You can use Ctrl
* to select all data or use F5>Special>Current region>OK with one
cell selected in the data range. If it copy all the data (there are a few
reports about this) use also the shortcut Alt ; or F5>Special>Visible cells
only>OK to select only the Visible cells.
2) Ctrl c
in all Excel versions or:
Excel 97-2003: Edit>Copy
Excel 2007-2013:
Home tab>Clipboard group>Copy
3) Shift F11 in all
Excel versions to insert a worksheet or:
Excel 97-2003: Insert>Worksheet
Excel 2007-2013: Home tab>Cells group>Insert...Sheet or use the button next
to the last tab
4) Ctrl v in all Excel versions or:
Excel 97-2003: Edit>Paste
Excel 2007-2013: Home tab>Clipboard group>Paste
5) Select the worksheet with the filter
6) Press Esc
7) Press Alt d f f in every
English Excel version or:
Excel 97-2003: Data>Filter>AutoFilter to turn
off AutoFilter.
Excel 2007-2013: Data tab>Sort & Filter>Filter