How to copy multiple rows, where cells have specific value.

Alex T

New Member
Joined
Mar 1, 2010
Messages
11
Good day,

I have a file "Customer List" that contains multiple customers in it and is being generated every week. This file has Columns A to K and can have different number or rows every time. One of the Columns (Customer_Name) is always constant.

I am looking for a VBA script that will allow me to scan through the entire file, search for the (Customer_Name) one at a time, copy all records for that client and paste it into the new File, then move to the next (Customer_Name) and do the same. So at the end i will have lets say 10 files with 10 different (Customer_Name) data in them.

Any help would be greatly appreciated.

Thank you.
 

Excel Facts

Did you know Excel offers Filter by Selection?
Add the AutoFilter icon to the Quick Access Toolbar. Select a cell containing Apple, click AutoFilter, and you will get all rows with Apple
When you say new file, do you mean new worksheet or new workbook?
 
Upvote 0
Hi mrnacar,

It is a new Worksheet.

Please let me know if you have more questions.

Thank you for replying back to me.
 
Upvote 0
I'll give credit to the guy who posted the following link:

http://www.rondebruin.nl/copy5_4.htm

Here is the code assuming "Customer_Name" is under column "A". You may need to modify FieldNum = 1 if your "Customer_Name" is under column "B" to FieldNum = 2, or 3 if "C", etc...

Code:
Sub Copy_To_Worksheets()
'Note: This macro use the function LastRow
    Dim My_Range As Range
    Dim FieldNum As Long
    Dim CalcMode As Long
    Dim ViewMode As Long
    Dim ws2 As Worksheet
    Dim Lrow As Long
    Dim cell As Range
    Dim CCount As Long
    Dim WSNew As Worksheet
    Dim ErrNum As Long
    '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:K" & 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
    'This example filters 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, ......
    FieldNum = 1
    'Turn off AutoFilter
    My_Range.Parent.AutoFilterMode = False
    '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
    'Add a worksheet to copy the a unique list and add the CriteriaRange
    Set ws2 = Worksheets.Add
    With ws2
        'first we copy the Unique data from the filter field to ws2
        My_Range.Columns(FieldNum).AdvancedFilter _
                Action:=xlFilterCopy, _
                CopyToRange:=.Range("A1"), Unique:=True
        'loop through the unique list in ws2 and filter/copy to a new sheet
        Lrow = .Cells(Rows.Count, "A").End(xlUp).Row
        For Each cell In .Range("A2:A" & Lrow)
            'Filter the range
            My_Range.AutoFilter Field:=FieldNum, Criteria1:="=" & _
             Replace(Replace(Replace(cell.Value, "~", "~~"), "*", "~*"), "?", "~?")
            'Check if there are no more then 8192 areas(limit of areas)
            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 for the value : " & cell.Value _
                     & vbNewLine & "It is not possible to copy the visible data." _
                     & vbNewLine & "Tip: Sort your data before you use this macro.", _
                       vbOKOnly, "Split in worksheets"
            Else
                'Add a new worksheet
                Set WSNew = Worksheets.Add(After:=Sheets(Sheets.Count))
                On Error Resume Next
                WSNew.Name = cell.Value
                If Err.Number > 0 Then
                    ErrNum = ErrNum + 1
                    WSNew.Name = "Error_" & Format(ErrNum, "0000")
                    Err.Clear
                End If
                On Error GoTo 0
                'Copy the visible data to the new worksheet
                My_Range.SpecialCells(xlCellTypeVisible).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
            End If
            'Show all data in the range
            My_Range.AutoFilter Field:=FieldNum
        Next cell
        'Delete the ws2 sheet
        On Error Resume Next
        Application.DisplayAlerts = False
        .Delete
        Application.DisplayAlerts = True
        On Error GoTo 0
    End With
    'Turn off AutoFilter
    My_Range.Parent.AutoFilterMode = False
    If ErrNum > 0 Then
        MsgBox "Rename every WorkSheet name that start with ""Error_"" manually" _
             & vbNewLine & "There are characters in the name that are not allowed" _
             & vbNewLine & "in a sheet name or the worksheet already exist."
    End If
    'Restore ScreenUpdating, Calculation, EnableEvents, ....
    My_Range.Parent.Select
    ActiveWindow.View = ViewMode
    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
 
Upvote 0
Assuming ..

1. The data is now on a sheet called 'Main' (edit code if another name).
2. The customer names are in column B - column 2 (edit code if different).
3. The individual customer sheets do not already exist.
4. None of your customer names are longer than 31 characters or contain characters that are not allowed in sheet names.

.. test this in a copy of your workbook.

<font face=Courier New><br><SPAN style="color:#00007F">Sub</SPAN> CreateCustomerSheets()<br>    <SPAN style="color:#00007F">Dim</SPAN> wsMain <SPAN style="color:#00007F">As</SPAN> Worksheet, wsCust <SPAN style="color:#00007F">As</SPAN> Worksheet<br>    <SPAN style="color:#00007F">Dim</SPAN> CustList()<br>    <SPAN style="color:#00007F">Dim</SPAN> n <SPAN style="color:#00007F">As</SPAN> <SPAN style="color:#00007F">Long</SPAN><br>    <br>    <SPAN style="color:#00007F">Set</SPAN> wsMain = Sheets("Main") <SPAN style="color:#007F00">'<-- Use your main sheet name</SPAN><br>    <SPAN style="color:#00007F">Const</SPAN> CustCol <SPAN style="color:#00007F">As</SPAN> <SPAN style="color:#00007F">Long</SPAN> = 2   <SPAN style="color:#007F00">'<-- Your customer column (2 = B)</SPAN><br>    <br>    Application.ScreenUpdating = <SPAN style="color:#00007F">False</SPAN><br>    <SPAN style="color:#00007F">With</SPAN> wsMain<br>        .Columns(CustCol).AdvancedFilter Action:=xlFilterCopy, _<br>            CopyToRange:=.Range("M1"), Unique:=<SPAN style="color:#00007F">True</SPAN><br>        CustList = .Range("M2", .Range("M2").End(xlDown)).Value<br>        .Columns("M").ClearContents<br>        <SPAN style="color:#00007F">For</SPAN> n = 1 <SPAN style="color:#00007F">To</SPAN> <SPAN style="color:#00007F">UBound</SPAN>(CustList, 1)<br>            Sheets.Add(After:=Sheets(Sheets.Count)).Name = CustList(n, 1)<br>            <SPAN style="color:#00007F">Set</SPAN> wsCust = ActiveSheet<br>            <SPAN style="color:#00007F">With</SPAN> .Columns(CustCol).Resize(.UsedRange.Rows.Count)<br>                .AutoFilter Field:=1, Criteria1:=CustList(n, 1)<br>                .EntireRow.Copy Destination:=wsCust.Range("A1")<br>            <SPAN style="color:#00007F">End</SPAN> <SPAN style="color:#00007F">With</SPAN><br>        <SPAN style="color:#00007F">Next</SPAN> n<br>        .AutoFilterMode = <SPAN style="color:#00007F">False</SPAN><br>    <SPAN style="color:#00007F">End</SPAN> <SPAN style="color:#00007F">With</SPAN><br>    Application.ScreenUpdating = <SPAN style="color:#00007F">True</SPAN><br><SPAN style="color:#00007F">End</SPAN> <SPAN style="color:#00007F">Sub</SPAN><br></FONT>
 
Upvote 0
Peter,

I like your code becuase it's short.

But it does not go real well if there are errors like sheet name exist or sheet name is too long. Your code stops in the middle and then the user has to delete all the sheets that exists and start over. Where as the other code completes the job even if there are errors and all the user has to do is rename the error sheet.

Assuming ..

1. The data is now on a sheet called 'Main' (edit code if another name).
2. The customer names are in column B - column 2 (edit code if different).
3. The individual customer sheets do not already exist.
4. None of your customer names are longer than 31 characters or contain characters that are not allowed in sheet names.

.. test this in a copy of your workbook.


Sub CreateCustomerSheets()
Dim wsMain As Worksheet, wsCust As Worksheet
Dim CustList()
Dim n As Long

Set wsMain = Sheets("Main") '<-- Use your main sheet name
Const CustCol As Long = 2 '<-- Your customer column (2 = B)

Application.ScreenUpdating = False
With wsMain
.Columns(CustCol).AdvancedFilter Action:=xlFilterCopy, _
CopyToRange:=.Range("M1"), Unique:=True
CustList = .Range("M2", .Range("M2").End(xlDown)).Value
.Columns("M").ClearContents
For n = 1 To UBound(CustList, 1)
Sheets.Add(After:=Sheets(Sheets.Count)).Name = CustList(n, 1)
Set wsCust = ActiveSheet
With .Columns(CustCol).Resize(.UsedRange.Rows.Count)
.AutoFilter Field:=1, Criteria1:=CustList(n, 1)
.EntireRow.Copy Destination:=wsCust.Range("A1")
End With
Next n
.AutoFilterMode = False
End With
Application.ScreenUpdating = True
End Sub
 
Upvote 0
But it does not go real well if there are errors like sheet name exist or sheet name is too long.
Yes, I did mention that in point 4 my assumptions. :)

If that is a problem for the OP I think that can be fixed with a few extra lines.
Rich (BB code):
For n = 1 To UBound(CustList, 1)
    On Error Resume Next
    Application.DisplayAlerts = False
    Sheets(CustList(n, 1)).Delete
    Application.DisplayAlerts = True
    Sheets.Add(After:=Sheets(Sheets.Count)).Name = CustList(n, 1)
    On Error GoTo 0
    Set wsCust = ActiveSheet
 
Upvote 0
Kewl! Thanks for the knowledge Peter. But I guess the OP will ultimately decide what he needs.

Yes, I did mention that in point 4 my assumptions. :)

If that is a problem for the OP I think that can be fixed with a few extra lines.
Rich (BB code):
For n = 1 To UBound(CustList, 1)
   On Error Resume Next
   Application.DisplayAlerts = False
   Sheets(CustList(n, 1)).Delete
   Application.DisplayAlerts = True
    Sheets.Add(After:=Sheets(Sheets.Count)).Name = CustList(n, 1)
    On Error GoTo 0
    Set wsCust = ActiveSheet
 
Upvote 0
Hi Guys,

Thank you very much. Your code works like magic. I really appreciate your effort.

If you dont mind i have 2 more questions :)

1. In the code there is a piece that copies the All Visible Cells into new Sheets

On Error GoTo 0
'Copy the visible data to the new worksheet
My_Range.SpecialCells(xlCellTypeVisible).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

'.PasteSpecial xlPasteFormulas
'.PasteSpecial xlPasteValidation

Application.CutCopyMode = False
.Select
End With
End If


I cant figure out how to copy Formulas and Validation from the main Sheet, i've tried all options of - SpecialCells(xlCellType.......) but none works.


2. Would you by any chance know how using VBA save the Sheet into the new File using Sheet's name?


Thank you very much for your help!
 
Upvote 0
1. In the code there is a piece that copies the All Visible Cells into new Sheets


I cant figure out how to copy Formulas and Validation from the main Sheet, i've tried all options of - SpecialCells(xlCellType.......) but none works.


2. Would you by any chance know how using VBA save the Sheet into the new File using Sheet's name?


Thank you very much for your help!

I think the following code should do the job:

But before you run the macro, either change the code path "C:\Test\" to your path or create a folder named "Test" under your "C" drive.

Code:
Sub Copy_To_Worksheets()
'Note: This macro use the function LastRow
    Dim My_Range As Range
    Dim FieldNum As Long
    Dim CalcMode As Long
    Dim ViewMode As Long
    Dim ws2 As Worksheet
    Dim Lrow As Long
    Dim cell As Range
    Dim CCount As Long
    Dim WSNew As Worksheet
    Dim ErrNum As Long
    '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:K" & 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
    'This example filters 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, ......
    FieldNum = 1
    'Turn off AutoFilter
    My_Range.Parent.AutoFilterMode = False
    '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
    'Add a worksheet to copy the a unique list and add the CriteriaRange
    Set ws2 = Worksheets.Add
    With ws2
        'first we copy the Unique data from the filter field to ws2
        My_Range.Columns(FieldNum).AdvancedFilter _
                Action:=xlFilterCopy, _
                CopyToRange:=.Range("A1"), Unique:=True
        'loop through the unique list in ws2 and filter/copy to a new sheet
        Lrow = .Cells(Rows.Count, "A").End(xlUp).Row
        For Each cell In .Range("A2:A" & Lrow)
            'Filter the range
            My_Range.AutoFilter Field:=FieldNum, Criteria1:="=" & _
             Replace(Replace(Replace(cell.Value, "~", "~~"), "*", "~*"), "?", "~?")
            'Check if there are no more then 8192 areas(limit of areas)
            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 for the value : " & cell.Value _
                     & vbNewLine & "It is not possible to copy the visible data." _
                     & vbNewLine & "Tip: Sort your data before you use this macro.", _
                       vbOKOnly, "Split in worksheets"
            Else
                'Add a new worksheet
                Set WSNew = Worksheets.Add(After:=Sheets(Sheets.Count))
                On Error Resume Next
                WSNew.Name = cell.Value
                If Err.Number > 0 Then
                    ErrNum = ErrNum + 1
                    WSNew.Name = "Error_" & Format(ErrNum, "0000")
                    Err.Clear
                End If
                On Error GoTo 0
                'Copy the visible data to the new worksheet
                My_Range.SpecialCells(xlCellTypeVisible).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 xlPasteValidation
                    .PasteSpecial xlPasteFormulasAndNumberFormats
                    Application.CutCopyMode = False
                    .Select
                End With
            End If
            'Show all data in the range
            My_Range.AutoFilter Field:=FieldNum
        Next cell
        'Delete the ws2 sheet
        On Error Resume Next
        Application.DisplayAlerts = False
        .Delete
        Application.DisplayAlerts = True
        On Error GoTo 0
    End With
    'Turn off AutoFilter
    My_Range.Parent.AutoFilterMode = False
    If ErrNum > 0 Then
        MsgBox "Rename every WorkSheet name that start with ""Error_"" manually" _
             & vbNewLine & "There are characters in the name that are not allowed" _
             & vbNewLine & "in a sheet name or the worksheet already exist."
    End If
    'Restore ScreenUpdating, Calculation, EnableEvents, ....
    My_Range.Parent.Select
    ActiveWindow.View = ViewMode
    With Application
        .ScreenUpdating = True
        .EnableEvents = True
        .Calculation = CalcMode
    End With
Dim wks As Worksheet
Worksheets.Select
For Each wks In ActiveWindow.SelectedSheets
wks.Copy 'to a new workbook
With ActiveSheet
.Parent.SaveAs Filename:="C:\Test\" & .Name & ".xls", _
FileFormat:=xlWorkbookNormal
.Parent.Close savechanges:=False
End With
Next wks
Shell ("explorer C:\Test"), vbMaximizedFocus
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
 
Upvote 0

Forum statistics

Threads
1,214,990
Messages
6,122,626
Members
449,094
Latest member
bsb1122

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