Copy Rows to New Sheet Based on Criteria

MaryD27

New Member
Joined
Jul 20, 2018
Messages
6
Good Morning!

I'm very new here. I'm working on a project for work and I'm totally stuck.

Here are the details:

I have a very large workbook containing quoting information. There are 28 different sheets representing different vendors. Each sheet contains quote numbers and quote information; the sheets range in size from 50 lines to 4000. The columns are headed as follows:

[TABLE="width: 500"]
<tbody>[TR]
[TD]Job Name[/TD]
[TD]Quote #[/TD]
[TD]Date[/TD]
[TD]Customer[/TD]
[TD]Quote Writer[/TD]
[TD]Quantity[/TD]
[TD]Models[/TD]
[TD]Amount[/TD]
[TD]Comments[/TD]
[TD]Follow-Up[/TD]
[TD]Assigned To[/TD]
[TD]Last Follow-up Date[/TD]
[TD]Status[/TD]
[/TR]
</tbody>[/TABLE]

When jobs are tagged for follow-up, an "X" is entered into the column.

I want a list of all the jobs that have been tagged for follow-up from every sheet. I need all the information (every column within the row) to copy to a new sheet or a new workbook. This will be done on a recurring basis, so I would like to make sure the same information is not duplicated.

I've seen VBA coding online of others trying to accomplish similar things, but I am very new to VBA and having trouble customizing the macros to my needs. If anyone has any codes or even formulas that could help, I really appreciate the input. I'd be happy to clarify anything, if you have questions.

Thanks in advance and Happy Friday!
 

Excel Facts

Do you hate GETPIVOTDATA?
Prevent GETPIVOTDATA. Select inside a PivotTable. In the Analyze tab of the ribbon, open the dropown next to Options and turn it off
Hello Mary,

See if the following code does the task for you:-


Code:
Sub Consolidate()

      Dim ws As Worksheet

Application.ScreenUpdating = False

For Each ws In Worksheets
             If ws.Name <> "Sheet1" Then
With ws.[A1].CurrentRegion
             .AutoFilter 10, "X"
             .Offset(1).EntireRow.Copy
             Sheet1.Range("A" & Rows.Count).End(3)(2).PasteSpecial xlValues
             .AutoFilter
             End With
       End If
Next ws

Application.CutCopyMode = False
Application.ScreenUpdating = True

End Sub

The code will filter Column J of each sheet (except your Master sheet) for the criteria "X" and then transfer the relevant rows of data to the Master sheet.

Change "Sheet1" to the name of your Master sheet in the code.

I hope that this helps.

Cheerio,
vcoolio.
 
Upvote 0
This macro will ensure that when you run the macro more than once, the same information will not be duplicated.
Code:
Sub CopyData()
    Application.ScreenUpdating = False
    Dim LastRow As Long
    LastRow = Cells.Find("*", SearchOrder:=xlByRows, SearchDirection:=xlPrevious).Row
    Dim ws As Worksheet
    On Error Resume Next
    Set ws = Sheets("Tagged Jobs")
    On Error GoTo 0
    If ws Is Nothing Then
        Worksheets.Add(before:=Sheets("Sheet1")).Name = "Tagged Jobs"
    End If
    Sheets("Tagged Jobs").UsedRange.ClearContents
    Sheets("Sheet1").Rows(1).Copy Cells(1, 1)
    For Each ws In Sheets
        If ws.Name <> "Tagged Jobs" Then
            LastRow = ws.Cells.Find("*", SearchOrder:=xlByRows, SearchDirection:=xlPrevious).Row
            With ws.Range("A1").CurrentRegion
                .AutoFilter Field:=10, Criteria1:="X"
                .Offset(1).SpecialCells(xlCellTypeVisible).EntireRow.Copy Sheets("Tagged Jobs").Cells(Rows.Count, "A").End(xlUp).Offset(1, 0)
                .AutoFilter
            End With
        End If
    Next ws
    Application.ScreenUpdating = True
End Sub
 
Upvote 0
Thank you so much, vCoolio! It seems to work. The data is populating, but an error pops up that says "AutoFilter method of Range class failed." Any idea what that means? Thank you again very much!
 
Upvote 0
Thank you too, mumps! This also seems to be working, but I'm also getting the "AutoFilter method of Range class failed." Thanks again! I appreciate it so much!
 
Upvote 0
Can you post a screen shot of what your data looks like? Section B at this link has instructions on how to post a screen shot: https://www.mrexcel.com/forum/board-announcements/127080-guidelines-forum-use.html Alternately, you could upload a copy of your file to a free site such as www.box.com. or www.dropbox.com. Once you do that, mark it for 'Sharing' and you will be given a link to the file that you can post here. If the workbook contains confidential information, you could replace it with generic data.
 
Upvote 0
OK, now I'm really going to be a pain in the a**. :laugh: Is it possible to add a second criteria to the filter? Like limiting the results to quotes from 01/01/18 and newer?
 
Upvote 0
Try:
Code:
Sub CopyData()
    Application.ScreenUpdating = False
    Dim LastRow As Long
    LastRow = Cells.Find("*", SearchOrder:=xlByRows, SearchDirection:=xlPrevious).Row
    Dim ws As Worksheet
    On Error Resume Next
    Set ws = Sheets("Tagged Jobs")
    On Error GoTo 0
    If ws Is Nothing Then
        Worksheets.Add(before:=Sheets("Sheet1")).Name = "Tagged Jobs"
    End If
    Sheets("Tagged Jobs").UsedRange.ClearContents
    Sheets("Sheet1").Rows(1).Copy Cells(1, 1)
    For Each ws In Sheets
        If ws.Name <> "Tagged Jobs" Then
            LastRow = ws.Cells.Find("*", SearchOrder:=xlByRows, SearchDirection:=xlPrevious).Row
            With ws.Range("A1").CurrentRegion
                .AutoFilter Field:=10, Criteria1:="X"
                .AutoFilter Field:=3, Criteria1:=">=1/1/2018"
                .Offset(1).SpecialCells(xlCellTypeVisible).EntireRow.Copy Sheets("Tagged Jobs").Cells(Rows.Count, "A").End(xlUp).Offset(1, 0)
                .AutoFilter
            End With
        End If
    Next ws
    Application.ScreenUpdating = True
End Sub
 
Upvote 0

Forum statistics

Threads
1,224,823
Messages
6,181,170
Members
453,021
Latest member
Justyna P

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