VBA search all matching values in column copy specific ranges to different sheet

devofish

Board Regular
Joined
Dec 10, 2016
Messages
68
After looking around, I distilled this code down https://www.techonthenet.com/excel/macros/search_for_string.php that partially achieves what I need. Most of the examples I've found usually copy entire rows along with the example I've submitted. I only need 2 offset values (columns C:D) copied and pasted into my table. Could someone tell me what the correct syntax is to replace the Rows code with the adjacent cells associated with the found value? Many thanks for your time and consultation. Thanks to these forums, I am learning so much about Excel and VBA (and my limits :laugh:).
Code:
Sub SearchMove()    
    Dim fValue As Integer
    Dim mValues As Integer
    On Error GoTo Err_Execute
        fValue = 1
        mValues = 2
       While Len(Range("A" & CStr(fValue)).Value) > 0
            If InStr(1, Range("E" & CStr(fValue)).Value, "chupacabras") > 0 Then
                 Rows(CStr(fValue) & ":" & CStr(fValue)).Copy  [COLOR=#ff0000]'need to copy associated value in C:D...not entire row...as a side note, what is the purpose of the & ":" &??[/COLOR]
                 Sheets("blah").Rows(CStr(mValues) & ":" & CStr(mValues)).PasteSpecial  [COLOR=#ff0000]'tried just Paste but gives an error...not sure why PasteSpecial works...maybe bc of entire row?[/COLOR]
                 LCopyToRow = LCopyToRow + 1
                 Sheets("temp").Select  [COLOR=#ff0000]'temp sheet will delete after routine[/COLOR]
            End If
           fValue = fValue + 1
       Wend
       Application.CutCopyMode = False
       Range("A1").Select
       Exit Sub
Err_Execute:
    MsgBox "Derp."
End Sub
 

Excel Facts

Remove leading & trailing spaces
Save as CSV to remove all leading and trailing spaces. It is faster than using TRIM().
As you haven't said where to copy the data I've copied to Columns C & D
Code:
Sub SearchMove()
    Dim fValue As Integer
    Dim mValues As Integer
    On Error GoTo Err_Execute
        fValue = 1
        mValues = 2
       While Len(Range("A" & CStr(fValue)).Value) > 0
            If InStr(1, Range("E" & CStr(fValue)).Value, "chupacabras") > 0 Then
                 Range("C" & fValue).Resize(, 2).Copy Sheets("blah").Range("C" & mValues).Resize(, 2)
                 mValues = mValues + 1
            End If
           fValue = fValue + 1
       Wend
       Application.CutCopyMode = False
       Range("A1").Select
       Exit Sub
Err_Execute:
    MsgBox "Derp."
End Sub
 
Upvote 0
Very much obliged. Works like a charm. Data needed to be copied to A & B so I just changed it to
Code:
[COLOR=#333333]                 Range("C" & fValue).Resize(, 2).Copy Sheets("blah").Range("A" & mValues).Resize(, 2)[/COLOR]
 
Upvote 0
Glad to help & thanks for the feedback
 
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