Consulting

Results 1 to 11 of 11

Thread: Solved: find, copy and paste

  1. #1

    Solved: find, copy and paste

    Hi guys

    I'm trying to build a find, copy and paste macro, sounds simple enough.
    It should find the word "report" in column H from sheet 1 and then move it to a different sheet and paste that row into the next available empty row on sheet 3.

    However, , all it seems to do at the moment is find the second instance of the word "report" and copy it into infinity....

    Don't suppose I could draw on your superness once more to give me a hand spotting the issue?

    [VBA]Dim lRealLastRow As Long
    Sheets("Sheet1").Select
    Cells.Find(What:="REPORT", After:=ActiveCell, LookIn:=xlFormulas, LookAt _
    :=xlPart, SearchOrder:=xlByRows, SearchDirection:=xlNext, MatchCase:= _
    False, SearchFormat:=False).Activate
    Range(Selection, Cells(ActiveCell.Row, 1)).Copy
    Sheets("Sheet3").Select
    Range("A:A").Select
    Do While ActiveCell > 0
    lineno = lineno + 1
    ActiveCell.Offset(1, 0).Select
    ActiveCell.PasteSpecial xlPasteValues
    Loop[/VBA]

    Been playing with it for ages, managed to stop it picking the first instance only due to a silly error, but I really can't figure out what I've done to mess it up this time!!

    Thanks

    Phel x

  2. #2
    Knowledge Base Approver VBAX Wizard p45cal's Avatar
    Joined
    Oct 2005
    Location
    Surrey UK
    Posts
    5,877
    Re:"from sheet 1 and then move it to a different sheet "
    please confirm you want to move rather than copy the row..
    (coding for moving is easier than for copying because you don't have to worry so much about the After:= parameter in the Find statement.)
    p45cal
    Everyone: If I've helped and you can't be bothered to acknowledge it, I can't be bothered to look at further posts from you.

  3. #3
    It has to be copied I'm afraid, the original entry has to remain intact. What I'm trying to create is another list, but only of the items with "report" in column H.

  4. #4
    Knowledge Base Approver VBAX Wizard p45cal's Avatar
    Joined
    Oct 2005
    Location
    Surrey UK
    Posts
    5,877
    Do you have to do this a lot? That is, is it worth programming for? You could do all rows in one hit by adding an Autofilter, selecting 'Custom' in column H's dropdown, choosing the 'contains' option on the left, typing "report" (without quotes) on the right, then copy and paste the results to sheet 3.
    (You can see I want to avoid coding for this one!)
    p45cal
    Everyone: If I've helped and you can't be bothered to acknowledge it, I can't be bothered to look at further posts from you.

  5. #5
    It forms a monthly report that will be built in also to provide an adhoc report function as part of a larger data migration macro. It also has to be applied to 36 different pages covering a year across three categories: doing a script that can then be applied to each page is the simplest way of doing it.

    The current manual process takes several hours a week to do, an automated solution is definately the way forward.

    This part of the script is only a small part of the complete project.

  6. #6
    Knowledge Base Approver VBAX Wizard p45cal's Avatar
    Joined
    Oct 2005
    Location
    Surrey UK
    Posts
    5,877
    This should get you started (I abandoned Find):[vba]Sub blah()
    'With ActiveSheet
    With ActiveWorkbook.Sheets("Sheet1")
    For Each cll In Intersect(.UsedRange, .Columns("H"))
    If InStr(UCase(cll.Value), "REPORT") > 0 Then
    cll.EntireRow.Copy ActiveWorkbook.Sheets("Sheet3").Cells(Rows.Count, 1).End(xlUp).Offset(1)
    End If
    Next cll
    End With 'activesheet
    End Sub[/vba]Assumes column 1 (A) of destination will always contain something to designate an already occupied row, otherwise you'll get overwriting - see red 1 in the code above.
    p45cal
    Everyone: If I've helped and you can't be bothered to acknowledge it, I can't be bothered to look at further posts from you.

  7. #7
    Thanks for that, works a treat. Certainly cleared up one headache for this project!

    Just out of curiosity, what was wrong with the Find function?

    Phel x

  8. #8
    Administrator
    VP-Knowledge Base
    VBAX Grand Master mdmackillop's Avatar
    Joined
    May 2004
    Location
    Scotland
    Posts
    14,489
    Location
    Find loops to the next item. Use the FindNext method.
    From VBA Help

    [VBA]
    With Worksheets(1).Range("a1:a500")
    Set c = .Find(2, lookin:=xlValues)
    If Not c Is Nothing Then
    firstAddress = c.Address
    Do
    c.Value = 5
    Set c = .FindNext(c)
    Loop While Not c Is Nothing And c.Address <> firstAddress
    End If
    End With

    [/VBA]
    MVP (Excel 2008-2010)

    Post a workbook with sample data and layout if you want a quicker solution.


    To help indent your macros try Smart Indent

    Please remember to mark threads 'Solved'

  9. #9
    Which explains why it wasn't getting past the first entry....d'oh!

    Thanks guys

    Phel x

  10. #10
    Administrator
    VP-Knowledge Base VBAX Grand Master mdmackillop's Avatar
    Joined
    May 2004
    Location
    Scotland
    Posts
    14,489
    Location
    [vba]Option Explicit
    Option Compare Text
    Sub CopyReport()
    Dim C As Range, Tgt As Range
    Dim FirstAddress As String
    With Worksheets(1).Range("H:H")
    Set C = .Find("Report", LookIn:=xlValues)
    If Not C Is Nothing Then
    FirstAddress = C.Address
    Do
    Set Tgt = Sheets(3).Cells(Rows.Count, "H").End(xlUp).Offset(1,-7)
    C.EntireRow.Copy Tgt
    Set C = .FindNext(C)
    Loop While Not C Is Nothing And C.Address <> FirstAddress
    End If
    End With
    End Sub[/vba]
    MVP (Excel 2008-2010)

    Post a workbook with sample data and layout if you want a quicker solution.


    To help indent your macros try Smart Indent

    Please remember to mark threads 'Solved'

  11. #11
    Administrator
    VP-Knowledge Base VBAX Grand Master mdmackillop's Avatar
    Joined
    May 2004
    Location
    Scotland
    Posts
    14,489
    Location
    For Cut rather than Copy

    [VBA]
    Option Explicit
    Option Compare Text
    Sub CutReport()
    Dim C As Range, Tgt As Range
    Dim FirstAddress As String
    With Worksheets(1).Range("H:H")
    Do
    Set C = .Find("Report", LookIn:=xlValues)
    If Not C Is Nothing Then
    Set Tgt = Sheets(3).Cells(Rows.Count, "H").End(xlUp).Offset(1).Offset(, -7)
    C.EntireRow.Cut Tgt
    End If
    Loop While Not C Is Nothing
    End With
    End Sub

    [/VBA]
    MVP (Excel 2008-2010)

    Post a workbook with sample data and layout if you want a quicker solution.


    To help indent your macros try Smart Indent

    Please remember to mark threads 'Solved'

Posting Permissions

  • You may not post new threads
  • You may not post replies
  • You may not post attachments
  • You may not edit your posts
  •