Searching for cells with specific background color, then pulling data from the same rows?

jmpatrick

Active Member
Joined
Aug 17, 2016
Messages
482
Office Version
  1. 365
Platform
  1. Windows
Happy Friday!

I have this code that searches the range CalendarFloorsColumn for cells whose background color is red. It takes the data it finds in those cells and copies it to a column on another sheet called BoiseRequests.

What I need to do is have it copy additional data from columns B and D from the same row as the found red cells.

If there's a red cell in row 500 of the CalendarFloorsColumn range it would copy the data from that cell as well as the data from B500 and D500 to cell A1, A2 and A3 of the BoiseRequests sheet. The next red cell found would copy data to the next row down (B1, B2 and B3) on BoiseRequests and so on. make sense?

Here's my fabulous code...

VBA Code:
Sub BoiseRequests()
    Dim MR As Excel.Range
    Dim rngCell As Excel.Range
    Dim rngCount As Long
    
    Set MR = Sheets("Calendar").Range("CalendarFloorsColumn")
    
    rngCount = 1
    
    For Each rngCell In MR
        If rngCell.DisplayFormat.Interior.Color = RGB(255, 0, 0) Then
            Sheets("BoiseRequests").Range("A" & rngCount) = rngCell.Value
            rngCount = rngCount + 1
        End If
    Next rngCell
End Sub
 

Excel Facts

Repeat Last Command
Pressing F4 adds dollar signs when editing a formula. When not editing, F4 repeats last command.
Which column is your CalendarFloorsColumn?
Also you said

Do you mean next row or next column?

Column O

I want the data from O, B and D from all the "red cell" rows to copy over to the second sheet.

Hope that makes sense.
 
Upvote 0
And what about the 2nd question?
 
Upvote 0
So the 1st red cell should populate A1, A2 & A3 & then the next one should populate A4, A5 & A6? Rather than B1, B2 & B3 like you originally said?
 
Upvote 0
Ok, how about
VBA Code:
Sub BoiseRequests()
    Dim MR As Excel.Range
    Dim rngCell As Excel.Range
    Dim rngCount As Long
    
    Set MR = Sheets("Calendar").Range("CalendarFloorsColumn")
    
    rngCount = 1
    
    For Each rngCell In MR
        If rngCell.DisplayFormat.Interior.Color = RGB(255, 0, 0) Then
            With Sheets("BoiseRequests").Range("A" & rngCount)
               .Value = rngCell.Value
               .Offset(, 1).Resize(, 2).Value = Array(Range("B" & rngCell.Row).Value, Range("D" & rngCell.Row).Value)
            End With
            rngCount = rngCount + 1
        End If
    Next rngCell
End Sub
 
Upvote 0
Ok, how about
VBA Code:
Sub BoiseRequests()
    Dim MR As Excel.Range
    Dim rngCell As Excel.Range
    Dim rngCount As Long
   
    Set MR = Sheets("Calendar").Range("CalendarFloorsColumn")
   
    rngCount = 1
   
    For Each rngCell In MR
        If rngCell.DisplayFormat.Interior.Color = RGB(255, 0, 0) Then
            With Sheets("BoiseRequests").Range("A" & rngCount)
               .Value = rngCell.Value
               .Offset(, 1).Resize(, 2).Value = Array(Range("B" & rngCell.Row).Value, Range("D" & rngCell.Row).Value)
            End With
            rngCount = rngCount + 1
        End If
    Next rngCell
End Sub

All that shows is the dates from the red cells (column O). No data from columns B and D.
 
Upvote 0
Ok, how about
VBA Code:
Sub BoiseRequests()
    Dim MR As Excel.Range
    Dim rngCell As Excel.Range
    Dim rngCount As Long
    Dim Ws As Worksheet
    
    Set Ws = Sheets("Calendar")
    Set MR = Ws.Range("CalendarFloorsColumn")
    
    rngCount = 1
    
    For Each rngCell In MR
        If rngCell.DisplayFormat.Interior.Color = RGB(255, 0, 0) Then
            With Sheets("BoiseRequests").Range("A" & rngCount)
               .Value = rngCell.Value
               .Offset(, 1).Resize(, 2).Value = Array(Ws.Range("B" & rngCell.Row).Value, Ws.Range("D" & rngCell.Row).Value)
            End With
            rngCount = rngCount + 1
        End If
    Next rngCell
End Sub
 
Upvote 0
Solution

Forum statistics

Threads
1,223,886
Messages
6,175,191
Members
452,616
Latest member
intern444

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