Copy data based on cell value

gfaulds

New Member
Joined
Jan 15, 2014
Messages
14
Office Version
  1. 365
Platform
  1. Windows
Hello,

I have a workbook where I want to copy specific row data based on the value of a cell in a column. Below is from my workbook. The goal is anytime there is an "x" in header "R", then the cell values from columns "A", "B" and "I" are copied onto a new sheet called "ROCC". Same thing goes for column "C" and "M. Copied to sheets called "CLCKIT" and "MERCH".

For below the columns are standard A-I

Thank you.

[TABLE="width: 897"]
<colgroup><col width="123" style="width: 92pt; mso-width-source: userset; mso-width-alt: 4498;"> <col width="367" style="width: 275pt; mso-width-source: userset; mso-width-alt: 13421;"> <col width="68" style="width: 51pt; mso-width-source: userset; mso-width-alt: 2486;" span="3"> <col width="37" style="width: 28pt; mso-width-source: userset; mso-width-alt: 1353;" span="3"> <col width="391" style="width: 293pt; mso-width-source: userset; mso-width-alt: 14299;"> <tbody>[TR]
[TD="width: 123, bgcolor: #D9D9D9"]Rest Rooms[/TD]
[TD="width: 367, bgcolor: #D9D9D9"]Inspect[/TD]
[TD="width: 68, bgcolor: #00B050"]þ[/TD]
[TD="width: 68, bgcolor: #EA3F32"]ý[/TD]
[TD="width: 68, bgcolor: #9BC2E6"]N/A[/TD]
[TD="width: 37, bgcolor: #8EA9DB"]R[/TD]
[TD="width: 37, bgcolor: #8EA9DB"]C[/TD]
[TD="width: 37, bgcolor: #8EA9DB"]M[/TD]
[TD="width: 391, bgcolor: #D9D9D9"]Notes[/TD]
[/TR]
[TR]
[TD="width: 123, bgcolor: #FFFF66"]Ceiling Lights[/TD]
[TD="width: 367, bgcolor: transparent"]All lit. no broken/stained lens[/TD]
[TD="bgcolor: transparent"] [/TD]
[TD="bgcolor: transparent"] [/TD]
[TD="bgcolor: transparent"] [/TD]
[TD="bgcolor: transparent"] [/TD]
[TD="bgcolor: transparent"] [/TD]
[TD="bgcolor: transparent"] [/TD]
[TD="bgcolor: transparent"] [/TD]
[/TR]
[TR]
[TD="width: 123, bgcolor: #FFFF66"]Fan[/TD]
[TD="width: 367, bgcolor: transparent"]Operational and clean[/TD]
[TD="bgcolor: transparent"] [/TD]
[TD="bgcolor: transparent"] [/TD]
[TD="width: 68, bgcolor: transparent"] [/TD]
[TD="width: 37, bgcolor: transparent"] [/TD]
[TD="width: 37, bgcolor: transparent"] [/TD]
[TD="width: 37, bgcolor: transparent"] [/TD]
[TD="bgcolor: transparent"] [/TD]
[/TR]
[TR]
[TD="bgcolor: #FFFF66"]Floor[/TD]
[TD="width: 367, bgcolor: transparent"]Swept & Mopped[/TD]
[TD="bgcolor: transparent"] [/TD]
[TD="bgcolor: transparent"] [/TD]
[TD="width: 68, bgcolor: transparent"] [/TD]
[TD="width: 37, bgcolor: transparent"] [/TD]
[TD="width: 37, bgcolor: transparent"] [/TD]
[TD="width: 37, bgcolor: transparent"] [/TD]
[TD="bgcolor: transparent"] [/TD]
[/TR]
[TR]
[TD="width: 123, bgcolor: #FFFF66"]Light Switch[/TD]
[TD="width: 367, bgcolor: transparent"]inspect for dirty and operational[/TD]
[TD="bgcolor: transparent"] [/TD]
[TD="bgcolor: transparent"] [/TD]
[TD="width: 68, bgcolor: transparent"] [/TD]
[TD="width: 37, bgcolor: transparent"] [/TD]
[TD="width: 37, bgcolor: transparent"] [/TD]
[TD="width: 37, bgcolor: transparent"] [/TD]
[TD="bgcolor: transparent"] [/TD]
[/TR]
[TR]
[TD="bgcolor: #FFFF66"]Mirror[/TD]
[TD="width: 367, bgcolor: transparent"]Clean[/TD]
[TD="bgcolor: transparent"] [/TD]
[TD="bgcolor: transparent"] [/TD]
[TD="width: 68, bgcolor: transparent"] [/TD]
[TD="width: 37, bgcolor: transparent"] [/TD]
[TD="width: 37, bgcolor: transparent"] [/TD]
[TD="width: 37, bgcolor: transparent"] [/TD]
[TD="bgcolor: transparent"] [/TD]
[/TR]
[TR]
[TD="width: 123, bgcolor: #FFFF66"]Paper Towel Dispenser[/TD]
[TD="width: 367, bgcolor: transparent"]Operational and full[/TD]
[TD="bgcolor: transparent"] [/TD]
[TD="bgcolor: transparent"] [/TD]
[TD="width: 68, bgcolor: transparent"] [/TD]
[TD="width: 37, bgcolor: transparent"] [/TD]
[TD="width: 37, bgcolor: transparent"] [/TD]
[TD="width: 37, bgcolor: transparent"] [/TD]
[TD="bgcolor: transparent"] [/TD]
[/TR]
[TR]
[TD="bgcolor: #FFFF66"]Sink[/TD]
[TD="width: 367, bgcolor: transparent"]Clean. Operational, not leaking, has soap[/TD]
[TD="bgcolor: transparent"] [/TD]
[TD="bgcolor: transparent"] [/TD]
[TD="width: 68, bgcolor: transparent"] [/TD]
[TD="width: 37, bgcolor: transparent"] [/TD]
[TD="width: 37, bgcolor: transparent"] [/TD]
[TD="width: 37, bgcolor: transparent"] [/TD]
[TD="bgcolor: transparent"] [/TD]
[/TR]
[TR]
[TD="width: 123, bgcolor: #FFFF66"]Toilet[/TD]
[TD="width: 367, bgcolor: transparent"]Clean. Operational, not leaking[/TD]
[TD="bgcolor: transparent"] [/TD]
[TD="bgcolor: transparent"] [/TD]
[TD="width: 68, bgcolor: transparent"] [/TD]
[TD="width: 37, bgcolor: transparent"] [/TD]
[TD="width: 37, bgcolor: transparent"] [/TD]
[TD="width: 37, bgcolor: transparent"] [/TD]
[TD="bgcolor: transparent"] [/TD]
[/TR]
[TR]
[TD="bgcolor: #FFFF66"]Toilet Paper[/TD]
[TD="width: 367, bgcolor: transparent"]Has holder. Is full[/TD]
[TD="bgcolor: transparent"]
[/TD]
[TD="bgcolor: transparent"]
[/TD]
[TD="width: 68, bgcolor: transparent"] [/TD]
[TD="width: 37, bgcolor: transparent"] [/TD]
[TD="width: 37, bgcolor: transparent"] [/TD]
[TD="width: 37, bgcolor: transparent"] [/TD]
[TD="bgcolor: transparent"] [/TD]
[/TR]
[TR]
[TD="bgcolor: #FFFF66"]Toilet Seat Gaskets[/TD]
[TD="width: 367, bgcolor: transparent"]Has holder. Is full[/TD]
[TD="bgcolor: transparent"] [/TD]
[TD="bgcolor: transparent"] [/TD]
[TD="width: 68, bgcolor: transparent"] [/TD]
[TD="width: 37, bgcolor: transparent"] [/TD]
[TD="width: 37, bgcolor: transparent"] [/TD]
[TD="width: 37, bgcolor: transparent"] [/TD]
[TD="bgcolor: transparent"] [/TD]
[/TR]
[TR]
[TD="width: 123, bgcolor: #FFFF66"]Doors[/TD]
[TD="width: 367, bgcolor: transparent"]Clean. Freely open/close. Not sticking.[/TD]
[TD="bgcolor: transparent"] [/TD]
[TD="bgcolor: transparent"] [/TD]
[TD="width: 68, bgcolor: transparent"] [/TD]
[TD="width: 37, bgcolor: transparent"] [/TD]
[TD="width: 37, bgcolor: transparent"] [/TD]
[TD="width: 37, bgcolor: transparent"] [/TD]
[TD="bgcolor: transparent"] [/TD]
[/TR]
[TR]
[TD="bgcolor: #FFFF66"]Public Restroom[/TD]
[TD="width: 367, bgcolor: transparent"]Nothing is stored in the restroom if its public.(mop, bucket, chemicals, etc.)[/TD]
[TD="bgcolor: transparent"] [/TD]
[TD="bgcolor: transparent"] [/TD]
[TD="width: 68, bgcolor: transparent"] [/TD]
[TD="width: 37, bgcolor: transparent"] [/TD]
[TD="width: 37, bgcolor: transparent"] [/TD]
[TD="width: 37, bgcolor: transparent"] [/TD]
[TD="bgcolor: transparent"] [/TD]
[/TR]
</tbody>[/TABLE]
 

Excel Facts

Show numbers in thousands?
Use a custom number format of #,##0,K. Each comma after the final 0 will divide the displayed number by another thousand
I guess your "master" sheet has a structure of columns and rows like this:

<table style="font-family:Arial; font-size:12pt; border-style: groove ;border-color:#0000FF;background-color:#fffcf9; color:#000000; "><tr><td ><b>Master</b></td></tr></table>
<table border="1" cellspacing="0" style="font-family:Calibri,Arial; font-size:11pt; background-color:#ffffff; "> <colgroup><col style="font-weight:bold; width:30px; " /><col style="width:129.27px;" /><col style="width:281.35px;" /><col style="width:76.04px;" /><col style="width:76.04px;" /><col style="width:76.04px;" /><col style="width:76.04px;" /><col style="width:76.04px;" /><col style="width:76.04px;" /><col style="width:76.04px;" /></colgroup><tr style="background-color:#cacaca; text-align:center; font-weight:bold; font-size:8pt; "><td > </td><td >A</td><td >B</td><td >C</td><td >D</td><td >E</td><td >F</td><td >G</td><td >H</td><td >I</td></tr><tr style="height:29px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >1</td><td style="background-color:#d9d9d9; font-size:12pt; ">Rest Rooms</td><td style="background-color:#d9d9d9; font-size:12pt; ">Inspect</td><td style="background-color:#00b050; font-family:Wingdings; font-size:18pt; ">þ</td><td style="background-color:#ea3f32; color:#ffffff; font-family:Wingdings; font-size:18pt; ">ý</td><td style="background-color:#9bc2e6; font-size:12pt; ">N/A</td><td style="background-color:#8ea9db; font-size:12pt; ">R</td><td style="background-color:#8ea9db; font-size:12pt; ">C</td><td style="background-color:#8ea9db; font-size:12pt; ">M</td><td style="background-color:#d9d9d9; font-size:12pt; ">Notes</td></tr><tr style="height:19px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >2</td><td style="background-color:#ffff66; font-size:10pt; ">Ceiling Lights</td><td style="background-color:#fafafa; font-size:10pt; ">All lit. no broken/stained lens</td><td style="background-color:#fafafa; color:#333333; font-family:Verdana; font-size:9pt; "> </td><td style="background-color:#fafafa; color:#333333; font-family:Verdana; font-size:9pt; "> </td><td style="background-color:#fafafa; color:#333333; font-family:Verdana; font-size:9pt; "> </td><td style="background-color:#fafafa; color:#333333; font-family:Verdana; font-size:9pt; "> </td><td style="background-color:#fafafa; color:#333333; font-family:Verdana; font-size:9pt; "> </td><td style="background-color:#fafafa; color:#333333; font-family:Verdana; font-size:9pt; "> </td><td style="background-color:#fafafa; color:#333333; font-family:Verdana; font-size:9pt; "> </td></tr><tr style="height:19px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >3</td><td style="background-color:#ffff66; font-size:10pt; ">Fan</td><td style="background-color:#fafafa; font-size:10pt; ">Operational and clean</td><td style="background-color:#fafafa; color:#333333; font-family:Verdana; font-size:9pt; "> </td><td style="background-color:#fafafa; color:#333333; font-family:Verdana; font-size:9pt; "> </td><td style="background-color:#fafafa; color:#333333; font-family:Verdana; font-size:9pt; "> </td><td style="background-color:#fafafa; color:#333333; font-family:Verdana; font-size:9pt; ">x</td><td style="background-color:#fafafa; color:#333333; font-family:Verdana; font-size:9pt; "> </td><td style="background-color:#fafafa; color:#333333; font-family:Verdana; font-size:9pt; "> </td><td style="background-color:#fafafa; color:#333333; font-family:Verdana; font-size:9pt; ">some note</td></tr><tr style="height:19px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >4</td><td style="background-color:#ffff66; font-size:10pt; ">Floor</td><td style="background-color:#fafafa; font-size:10pt; ">Swept & Mopped</td><td style="background-color:#fafafa; color:#333333; font-family:Verdana; font-size:9pt; "> </td><td style="background-color:#fafafa; color:#333333; font-family:Verdana; font-size:9pt; "> </td><td style="background-color:#fafafa; color:#333333; font-family:Verdana; font-size:9pt; "> </td><td style="background-color:#fafafa; color:#333333; font-family:Verdana; font-size:9pt; "> </td><td style="background-color:#fafafa; color:#333333; font-family:Verdana; font-size:9pt; "> </td><td style="background-color:#fafafa; color:#333333; font-family:Verdana; font-size:9pt; ">x</td><td style="background-color:#fafafa; color:#333333; font-family:Verdana; font-size:9pt; "> </td></tr><tr style="height:19px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >5</td><td style="background-color:#ffff66; font-size:10pt; ">Light Switch</td><td style="background-color:#fafafa; font-size:10pt; ">inspect for dirty and operational</td><td style="background-color:#fafafa; color:#333333; font-family:Verdana; font-size:9pt; "> </td><td style="background-color:#fafafa; color:#333333; font-family:Verdana; font-size:9pt; "> </td><td style="background-color:#fafafa; color:#333333; font-family:Verdana; font-size:9pt; "> </td><td style="background-color:#fafafa; color:#333333; font-family:Verdana; font-size:9pt; ">x</td><td style="background-color:#fafafa; color:#333333; font-family:Verdana; font-size:9pt; ">x</td><td style="background-color:#fafafa; color:#333333; font-family:Verdana; font-size:9pt; "> </td><td style="background-color:#fafafa; color:#333333; font-family:Verdana; font-size:9pt; "> </td></tr><tr style="height:19px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >6</td><td style="background-color:#ffff66; font-size:10pt; ">Mirror</td><td style="background-color:#fafafa; font-size:10pt; ">Clean</td><td style="background-color:#fafafa; color:#333333; font-family:Verdana; font-size:9pt; "> </td><td style="background-color:#fafafa; color:#333333; font-family:Verdana; font-size:9pt; "> </td><td style="background-color:#fafafa; color:#333333; font-family:Verdana; font-size:9pt; "> </td><td style="background-color:#fafafa; color:#333333; font-family:Verdana; font-size:9pt; "> </td><td style="background-color:#fafafa; color:#333333; font-family:Verdana; font-size:9pt; "> </td><td style="background-color:#fafafa; color:#333333; font-family:Verdana; font-size:9pt; "> </td><td style="background-color:#fafafa; color:#333333; font-family:Verdana; font-size:9pt; "> </td></tr><tr style="height:19px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >7</td><td style="background-color:#ffff66; font-size:10pt; ">Paper Towel Dispenser</td><td style="background-color:#fafafa; font-size:10pt; ">Operational and full</td><td style="background-color:#fafafa; color:#333333; font-family:Verdana; font-size:9pt; "> </td><td style="background-color:#fafafa; color:#333333; font-family:Verdana; font-size:9pt; "> </td><td style="background-color:#fafafa; color:#333333; font-family:Verdana; font-size:9pt; "> </td><td style="background-color:#fafafa; color:#333333; font-family:Verdana; font-size:9pt; ">x</td><td style="background-color:#fafafa; color:#333333; font-family:Verdana; font-size:9pt; "> </td><td style="background-color:#fafafa; color:#333333; font-family:Verdana; font-size:9pt; "> </td><td style="background-color:#fafafa; color:#333333; font-family:Verdana; font-size:9pt; "> </td></tr><tr style="height:19px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >8</td><td style="background-color:#ffff66; font-size:10pt; ">Sink</td><td style="background-color:#fafafa; font-size:10pt; ">Clean. Operational, not leaking, has soap</td><td style="background-color:#fafafa; color:#333333; font-family:Verdana; font-size:9pt; "> </td><td style="background-color:#fafafa; color:#333333; font-family:Verdana; font-size:9pt; "> </td><td style="background-color:#fafafa; color:#333333; font-family:Verdana; font-size:9pt; "> </td><td style="background-color:#fafafa; color:#333333; font-family:Verdana; font-size:9pt; "> </td><td style="background-color:#fafafa; color:#333333; font-family:Verdana; font-size:9pt; "> </td><td style="background-color:#fafafa; color:#333333; font-family:Verdana; font-size:9pt; "> </td><td style="background-color:#fafafa; color:#333333; font-family:Verdana; font-size:9pt; "> </td></tr><tr style="height:19px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >9</td><td style="background-color:#ffff66; font-size:10pt; ">Toilet</td><td style="background-color:#fafafa; font-size:10pt; ">Clean. Operational, not leaking</td><td style="background-color:#fafafa; color:#333333; font-family:Verdana; font-size:9pt; "> </td><td style="background-color:#fafafa; color:#333333; font-family:Verdana; font-size:9pt; "> </td><td style="background-color:#fafafa; color:#333333; font-family:Verdana; font-size:9pt; "> </td><td style="background-color:#fafafa; color:#333333; font-family:Verdana; font-size:9pt; "> </td><td style="background-color:#fafafa; color:#333333; font-family:Verdana; font-size:9pt; ">x</td><td style="background-color:#fafafa; color:#333333; font-family:Verdana; font-size:9pt; "> </td><td style="background-color:#fafafa; color:#333333; font-family:Verdana; font-size:9pt; "> </td></tr><tr style="height:19px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >10</td><td style="background-color:#ffff66; font-size:10pt; ">Toilet Paper</td><td style="background-color:#fafafa; font-size:10pt; ">Has holder. Is full</td><td style="background-color:#fafafa; color:#333333; font-family:Verdana; font-size:9pt; "> </td><td style="background-color:#fafafa; color:#333333; font-family:Verdana; font-size:9pt; "> </td><td style="background-color:#fafafa; color:#333333; font-family:Verdana; font-size:9pt; "> </td><td style="background-color:#fafafa; color:#333333; font-family:Verdana; font-size:9pt; "> </td><td style="background-color:#fafafa; color:#333333; font-family:Verdana; font-size:9pt; "> </td><td style="background-color:#fafafa; color:#333333; font-family:Verdana; font-size:9pt; "> </td><td style="background-color:#fafafa; color:#333333; font-family:Verdana; font-size:9pt; "> </td></tr><tr style="height:19px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >11</td><td style="background-color:#ffff66; font-size:10pt; ">Toilet Seat Gaskets</td><td style="background-color:#fafafa; font-size:10pt; ">Has holder. Is full</td><td style="background-color:#fafafa; color:#333333; font-family:Verdana; font-size:9pt; "> </td><td style="background-color:#fafafa; color:#333333; font-family:Verdana; font-size:9pt; "> </td><td style="background-color:#fafafa; color:#333333; font-family:Verdana; font-size:9pt; "> </td><td style="background-color:#fafafa; color:#333333; font-family:Verdana; font-size:9pt; "> </td><td style="background-color:#fafafa; color:#333333; font-family:Verdana; font-size:9pt; "> </td><td style="background-color:#fafafa; color:#333333; font-family:Verdana; font-size:9pt; ">x</td><td style="background-color:#fafafa; color:#333333; font-family:Verdana; font-size:9pt; "> </td></tr><tr style="height:19px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >12</td><td style="background-color:#ffff66; font-size:10pt; ">Doors</td><td style="background-color:#fafafa; font-size:10pt; ">Clean. Freely open/close. Not sticking.</td><td style="background-color:#fafafa; color:#333333; font-family:Verdana; font-size:9pt; "> </td><td style="background-color:#fafafa; color:#333333; font-family:Verdana; font-size:9pt; "> </td><td style="background-color:#fafafa; color:#333333; font-family:Verdana; font-size:9pt; "> </td><td style="background-color:#fafafa; color:#333333; font-family:Verdana; font-size:9pt; "> </td><td style="background-color:#fafafa; color:#333333; font-family:Verdana; font-size:9pt; "> </td><td style="background-color:#fafafa; color:#333333; font-family:Verdana; font-size:9pt; "> </td><td style="background-color:#fafafa; color:#333333; font-family:Verdana; font-size:9pt; "> </td></tr><tr style="height:35px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >13</td><td style="background-color:#ffff66; font-size:10pt; ">Public Restroom</td><td style="background-color:#fafafa; font-size:10pt; ">Nothing is stored in the restroom if its public.(mop, bucket, chemicals, etc.)</td><td style="background-color:#fafafa; "> </td><td style="background-color:#fafafa; "> </td><td style="background-color:#fafafa; "> </td><td style="background-color:#fafafa; "> </td><td style="background-color:#fafafa; "> </td><td style="background-color:#fafafa; "> </td><td style="background-color:#fafafa; "> </td></tr></table>

Try with this code, change "Master" by the name of your sheet

Code:
Sub Copy_Data_based_on_cell_value()
    Dim sh1 As Worksheet, sh2 As Worksheet, sh3 As Worksheet, sh4 As Worksheet
    
    Set sh1 = Sheets("[COLOR=#ff0000]Master[/COLOR]")
    Set sh2 = Sheets("ROCC")
    Set sh3 = Sheets("CLCKIT")
    Set sh4 = Sheets("MERCH")
    
    For Each c In sh1.Range("A2", sh1.Range("A" & Rows.Count).End(xlUp))
        If sh1.Cells(c.Row, "F").Value = "x" Then _
            sh2.Range("A" & Rows.Count).End(xlUp)(2).Resize(1, 3).Value = Array(sh1.Range("A" & c.Row), sh1.Range("B" & c.Row), sh1.Range("I" & c.Row))
        If sh1.Cells(c.Row, "G").Value = "x" Then _
            sh3.Range("A" & Rows.Count).End(xlUp)(2).Resize(1, 3).Value = Array(sh1.Range("A" & c.Row), sh1.Range("B" & c.Row), sh1.Range("I" & c.Row))
        If sh1.Cells(c.Row, "H").Value = "x" Then _
            sh4.Range("A" & Rows.Count).End(xlUp)(2).Resize(1, 3).Value = Array(sh1.Range("A" & c.Row), sh1.Range("B" & c.Row), sh1.Range("I" & c.Row))
    Next
    MsgBox "Done"
End Sub
 
Upvote 0
Hi Dante,

Works great! Is there a way to have it clear the "ROCC", "CLICKIT" and "MERCH" sheets prior to loading the data?
 
Last edited:
Upvote 0
Hi Dante,

Works great! Is there a way to have it clear the "ROCC", "CLICKIT" and "MERCH" sheets prior to loading the data?

Try, Delete from row 2 down, assuming that in row 1 you have headers

Code:
Sub Copy_Data_based_on_cell_value()
    Dim sh1 As Worksheet, sh2 As Worksheet, sh3 As Worksheet, sh4 As Worksheet
    
    Set sh1 = Sheets("Master")
    Set sh2 = Sheets("ROCC")
    Set sh3 = Sheets("CLCKIT")
    Set sh4 = Sheets("MERCH")
[COLOR=#0000ff]    sh2.rows("2:" & rows.count).clearcontents
    sh3.rows("2:" & rows.count).clearcontents
    sh4.rows("2:" & rows.count).clearcontents[/COLOR]


    For Each c In sh1.Range("A2", sh1.Range("A" & Rows.Count).End(xlUp))
        If sh1.Cells(c.Row, "F").Value = "x" Then _
            sh2.Range("A" & Rows.Count).End(xlUp)(2).Resize(1, 3).Value = Array(sh1.Range("A" & c.Row), sh1.Range("B" & c.Row), sh1.Range("I" & c.Row))
        If sh1.Cells(c.Row, "G").Value = "x" Then _
            sh3.Range("A" & Rows.Count).End(xlUp)(2).Resize(1, 3).Value = Array(sh1.Range("A" & c.Row), sh1.Range("B" & c.Row), sh1.Range("I" & c.Row))
        If sh1.Cells(c.Row, "H").Value = "x" Then _
            sh4.Range("A" & Rows.Count).End(xlUp)(2).Resize(1, 3).Value = Array(sh1.Range("A" & c.Row), sh1.Range("B" & c.Row), sh1.Range("I" & c.Row))
    Next
    MsgBox "Done"
End Sub
 
Upvote 0

Forum statistics

Threads
1,223,231
Messages
6,170,884
Members
452,364
Latest member
springate

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