Consulting

Results 1 to 15 of 15

Thread: Moving Duplicate records from one worksheet to another

  1. #1
    VBAX Mentor
    Joined
    May 2010
    Location
    London
    Posts
    307
    Location

    Moving Duplicate records from one worksheet to another

    Hi Everyone ,

    I have got a list which has duplicate records based on the data in column A. What I need to do is cut and paste those records into the new worksheet. Can anyone help me on this please? I attached a sample file with before after scenario.

    Cheers
    B.
    Attached Files Attached Files
    Sub Learning VBA()

    Do
    Practice Most Useful VBA Examples
    Loop Until Become an Expert in VBA

    End Sub

  2. #2
    snb
    Guest
    Sub M_snb()
       sp = Sheets("before").Cells(1).CurrentRegion
       sn = Filter([transpose(if(A1:A200="","~",if(countif($A$1:$A$200,A1:A200)=1,row(A1:A200),"~")))], "~", False)
       
       Sheets("after").Cells(20, 1).Resize(UBound(sn) + 1, UBound(sp, 2)) = Application.Index(sp, Application.Transpose(sn), Array(1, 2, 3, 4))
    End Sub

  3. #3
    VBAX Mentor
    Joined
    May 2010
    Location
    London
    Posts
    307
    Location
    Thanks very much for you reply snb. But I need to cut and paste those records into the new tab. Lets say I have entire list in before worksheet. After worksheet is blank. When I run the script duplicates must be removed from before list and paste to the after list. At the end, I should have unique records (based on column A) in before tab and dups in after tab.

    This script doesn't do that

    Cheers
    B.


    Quote Originally Posted by snb View Post
    Sub M_snb()
       sp = Sheets("before").Cells(1).CurrentRegion
       sn = Filter([transpose(if(A1:A200="","~",if(countif($A$1:$A$200,A1:A200)=1,row(A1:A200),"~")))], "~", False)
       
       Sheets("after").Cells(20, 1).Resize(UBound(sn) + 1, UBound(sp, 2)) = Application.Index(sp, Application.Transpose(sn), Array(1, 2, 3, 4))
    End Sub
    Sub Learning VBA()

    Do
    Practice Most Useful VBA Examples
    Loop Until Become an Expert in VBA

    End Sub

  4. #4
    snb
    Guest
    I showed you a method.

    So you will have to adapt the code: the best way to master VBA.

  5. #5
    VBAX Mentor
    Joined
    May 2010
    Location
    London
    Posts
    307
    Location
    Thanks I understand that and I did adapt it to my code but it doesn't copy paste right records. If data in column A (lets say C1468) in before list does repeat then those 2 rows need to be moved to the new tab. When I use your method it just lists the unique records in new tab not the dups.

    Here is the script I modified.

    Sub M_snb()
        sp = Sheets("master2").Cells(1).CurrentRegion
        sn = Filter([transpose(If(A1:A1000="","~",If(countif($A$1:$A$1000,A1:A1000)=1,row(A1:A1000),"~")))], "~", False)
         
        Sheets("master3").Cells(1, 1).Resize(UBound(sn) + 1, UBound(sp, 2)) = Application.Index(sp, Application.Transpose(sn), Array(1, 2, 3, 4, 5, 6, 7, 8, 9, 10, 11))
    End Sub



    Quote Originally Posted by snb View Post
    I showed you a method.

    So you will have to adapt the code: the best way to master VBA.
    Sub Learning VBA()

    Do
    Practice Most Useful VBA Examples
    Loop Until Become an Expert in VBA

    End Sub

  6. #6
    snb
    Guest
    to retrieve the dups ( it's only 1 character difference):

    Sub M_snb() 
        sp = Sheets("master2").Cells(1).CurrentRegion 
        sn = Filter([transpose(If(A1:A1000="","~",If(countif($A$1:$A$1000,A1:A1000)>1,row(A1:A1000),"~")))], "~", False) 
         
        Sheets("master3").Cells(1, 1).Resize(UBound(sn) + 1, UBound(sp, 2)) = Application.Index(sp, Application.Transpose(sn), Array(1, 2, 3, 4, 5, 6, 7, 8, 9, 10, 11)) 
    End Sub

  7. #7
    VBAX Guru mancubus's Avatar
    Joined
    Dec 2010
    Location
    "Where I lay my head is home" :D
    Posts
    2,645
    @snb
    if Sheets("before") is not active sheet, it throws "run time error 13, type mismatch."
    any comments as to why?




    and consolidation of subprocedures can be as follows:

    Sub M_snb()
    
        With Sheets("before")
            .Activate
            sp = .Cells(1).CurrentRegion
        End With
        
        sn = Filter([Transpose(If(A1:A15000="","~",If(CountIf($A$1:$A$15000,A1:A15000)=1,Row(A1:A15000),"~")))], "~", False)
        sq = Filter([Transpose(If(A1:A15000="","~",If(CountIf($A$1:$A$15000,A1:A15000)>1,Row(A1:A15000),"~")))], "~", False)
        
        With Sheets("before")
            .Cells(1).CurrentRegion.ClearContents
            .Cells(1).Resize(UBound(sn) + 1, UBound(sp, 2)) = Application.Index(sp, Application.Transpose(sn), Array(1, 2, 3, 4))
        End With
        
        Sheets("duplicate records").Cells(1).Resize(UBound(sq) + 1, UBound(sp, 2)) = Application.Index(sp, Application.Transpose(sq), Array(1, 2, 3, 4))
    
    End Sub
    PLS DO NOT PM; OPEN A THREAD INSTEAD!!!

    1) Posting Code
    [CODE]PasteYourCodeHere[/CODE]
    (or paste your code, select it, click # button)

    2) Uploading File(s)
    Go Advanced / Attachments - Manage Attachments / Add Files / Select Files / Select the file(s) (multiple files can be selected while holding Ctrl key) / Upload Files / Done
    Replace company specific / sensitive / confidential data. Include so many rows and sheets etc in the uploaded workbook to enable the helpers visualize the data and table structure. Helpers do not need the entire workbook.

    3) Testing the Codes
    always back up your files before testing the codes.

    4) Marking the Thread as Solved
    from Thread Tools (on the top right corner, above the first message)

  8. #8
    VBAX Mentor
    Joined
    May 2010
    Location
    London
    Posts
    307
    Location
    got it ">" thanks snb!!!! I wish I could have your knowledge

    Quote Originally Posted by snb View Post
    to retrieve the dups ( it's only 1 character difference):

    Sub M_snb() 
        sp = Sheets("master2").Cells(1).CurrentRegion 
        sn = Filter([transpose(If(A1:A1000="","~",If(countif($A$1:$A$1000,A1:A1000)>1,row(A1:A1000),"~")))], "~", False) 
         
        Sheets("master3").Cells(1, 1).Resize(UBound(sn) + 1, UBound(sp, 2)) = Application.Index(sp, Application.Transpose(sn), Array(1, 2, 3, 4, 5, 6, 7, 8, 9, 10, 11)) 
    End Sub
    Sub Learning VBA()

    Do
    Practice Most Useful VBA Examples
    Loop Until Become an Expert in VBA

    End Sub

  9. #9
    snb
    Guest
    @mancubus

    I always put the macro that works with the data in a certain sheet in the codemodule of that sheet.
    In this case the macro resides in the code module of sheet 'before'.
    I rarely create macromodules.

  10. #10
    VBAX Guru mancubus's Avatar
    Joined
    Dec 2010
    Location
    "Where I lay my head is home" :D
    Posts
    2,645
    @snb

    thanks for the reply.
    apparently ranges in formulas without sheet references assume active sheet.
    but when i tried adding worksheet reference to the formulas it did't work either.

    sn = Filter([Transpose(If(before!A1:A15000="","~",If(CountIf(before!$A$1:$A$15000,before!A1:A15000)=1,Row(A1:A15000),"~")))], "~", False)
    PLS DO NOT PM; OPEN A THREAD INSTEAD!!!

    1) Posting Code
    [CODE]PasteYourCodeHere[/CODE]
    (or paste your code, select it, click # button)

    2) Uploading File(s)
    Go Advanced / Attachments - Manage Attachments / Add Files / Select Files / Select the file(s) (multiple files can be selected while holding Ctrl key) / Upload Files / Done
    Replace company specific / sensitive / confidential data. Include so many rows and sheets etc in the uploaded workbook to enable the helpers visualize the data and table structure. Helpers do not need the entire workbook.

    3) Testing the Codes
    always back up your files before testing the codes.

    4) Marking the Thread as Solved
    from Thread Tools (on the top right corner, above the first message)

  11. #11
    VBAX Guru mancubus's Avatar
    Joined
    Dec 2010
    Location
    "Where I lay my head is home" :D
    Posts
    2,645
    _added_to_previous_post_
    Last edited by mancubus; 10-23-2014 at 01:00 AM.
    PLS DO NOT PM; OPEN A THREAD INSTEAD!!!

    1) Posting Code
    [CODE]PasteYourCodeHere[/CODE]
    (or paste your code, select it, click # button)

    2) Uploading File(s)
    Go Advanced / Attachments - Manage Attachments / Add Files / Select Files / Select the file(s) (multiple files can be selected while holding Ctrl key) / Upload Files / Done
    Replace company specific / sensitive / confidential data. Include so many rows and sheets etc in the uploaded workbook to enable the helpers visualize the data and table structure. Helpers do not need the entire workbook.

    3) Testing the Codes
    always back up your files before testing the codes.

    4) Marking the Thread as Solved
    from Thread Tools (on the top right corner, above the first message)

  12. #12
    snb
    Guest
    See the attachment
    Attached Files Attached Files

  13. #13
    VBAX Guru mancubus's Avatar
    Joined
    Dec 2010
    Location
    "Where I lay my head is home" :D
    Posts
    2,645
    thanks.

    since the only difference is the number of rows in range references (200 vs 15000), testing for the maximum number before running the code might be important.



    is it deja vu did i somehow ask the same questions before?
    PLS DO NOT PM; OPEN A THREAD INSTEAD!!!

    1) Posting Code
    [CODE]PasteYourCodeHere[/CODE]
    (or paste your code, select it, click # button)

    2) Uploading File(s)
    Go Advanced / Attachments - Manage Attachments / Add Files / Select Files / Select the file(s) (multiple files can be selected while holding Ctrl key) / Upload Files / Done
    Replace company specific / sensitive / confidential data. Include so many rows and sheets etc in the uploaded workbook to enable the helpers visualize the data and table structure. Helpers do not need the entire workbook.

    3) Testing the Codes
    always back up your files before testing the codes.

    4) Marking the Thread as Solved
    from Thread Tools (on the top right corner, above the first message)

  14. #14
    snb
    Guest
    @mancubus:

    You autofilled data to row 15000; resulting in no unique records.
    In that case the code errors out. Not because of the amount of rows nor because of referring to a sheet, nor because of the limitations of transpose.

  15. #15
    VBAX Guru mancubus's Avatar
    Joined
    Dec 2010
    Location
    "Where I lay my head is home" :D
    Posts
    2,645
    @snb

    actually i tried it with the OP's file.
    it's working now on the same file now.

    thanks for your time and explanation.
    PLS DO NOT PM; OPEN A THREAD INSTEAD!!!

    1) Posting Code
    [CODE]PasteYourCodeHere[/CODE]
    (or paste your code, select it, click # button)

    2) Uploading File(s)
    Go Advanced / Attachments - Manage Attachments / Add Files / Select Files / Select the file(s) (multiple files can be selected while holding Ctrl key) / Upload Files / Done
    Replace company specific / sensitive / confidential data. Include so many rows and sheets etc in the uploaded workbook to enable the helpers visualize the data and table structure. Helpers do not need the entire workbook.

    3) Testing the Codes
    always back up your files before testing the codes.

    4) Marking the Thread as Solved
    from Thread Tools (on the top right corner, above the first message)

Posting Permissions

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