Merging Worksheets with VBA

helpexcel

Well-known Member
Joined
Oct 21, 2009
Messages
656
I have a workbook with 2 worksheets of data. Client data 1 and Client data 2. Both of these worksheets contain duplicate and exclussive information. I could reorder the colums and do a vlookup to complie the data, but i would still have seperate sheets. I would like all the data in one location. I would like to run a macro that combines both worksheets into 1. This would save me time as I will have to do this multiple times, with multiple reports. The trick is, i don't want to copy the duplicate data. Can I write language that will look at the headers, match them up and only copy once, while copying all the columns that are exclusive to each sheet. The other wrinkle is that the headers might not be the same. For example the client name header in "Client data 1" will read Client name, while it will read Client on "Client data 2". It also couldn't blindly copy the column, because the data might not line up row by row in each sheet. Am I looking to do the impossible? Any help would be appreciate.



Client Data 1</SPAN>
Client</SPAN>Account Number</SPAN>Job Location</SPAN>Quote</SPAN>Job ID</SPAN>Division</SPAN>
ABC Company</SPAN>1234567</SPAN>The Gardens</SPAN>$1 </SPAN>98765</SPAN>3</SPAN>
ABC Company</SPAN>1234567</SPAN>Highway</SPAN>$5 </SPAN>56789</SPAN>7</SPAN>
Client Data 2</SPAN>
Client Number</SPAN>Client Name</SPAN>Job Date</SPAN>Est. time</SPAN>Job Code</SPAN>Job ID</SPAN>
1234567</SPAN>ABC Compnay</SPAN>4/1/2013</SPAN>4 months</SPAN>5</SPAN>56789</SPAN>
1234567</SPAN>ABC Compnay</SPAN>05/01/2013</SPAN>2 months</SPAN>1</SPAN>98765</SPAN>
Merged Data (what I'm Looking to accomplish)</SPAN>
Client</SPAN>Account Number</SPAN>Job Location</SPAN>Quote</SPAN>Job ID</SPAN>Division</SPAN>Job Date</SPAN>Est. Time</SPAN>Job Code</SPAN>
ABC Company</SPAN>1234567</SPAN>The Gardens</SPAN>$1 </SPAN>98765</SPAN>3</SPAN>05/01/2013</SPAN>2 months</SPAN>1</SPAN>
ABC Company</SPAN>1234567</SPAN>Highway</SPAN>$5 </SPAN>56789</SPAN>7</SPAN>4/1/2013</SPAN>4 months</SPAN>5</SPAN>

<TBODY>
</TBODY><COLGROUP><COL><COL><COL><COL><COL span=5></COLGROUP>
 

Excel Facts

Ambidextrous Undo
Undo last command with Ctrl+Z or Alt+Backspace. If you use the Undo icon in the QAT, open the drop-down arrow to undo up to 100 steps.
This assumes you will start with a blank worksheet, except for headers, in the same workbook and that the headers will be in consecutive columns and in the order shown in the post. sh3 variable will be used as the merged sheet.
Code:
Sub merge()
Dim sh1 As Worksheet, sh2 As Worksheet, sh3 As Worksheet, lr As Long, rw As Long, fRw As Long
Dim rng As Range, c As Range, fID As Range
Set sh1 = Sheets("Client 1") 'Edit sheet name
Set sh2 = Sheets("Client 2") 'Edit sheet name
Set sh3 = Sheets(3) 'Edit sheet name
lr = sh1.Cells(Rows.Count, 5).End(xlUp).Row
Set rng = sh1.Range("E2:E" & lr)
    For Each c In rng
        rw = c.Row
        Set fID = sh2.Range("F:F").Find(c.Value, LookIn:=xlValues)
            If Not fID Is Nothing Then
                fRw = fID.Row
                sh1.Range("A" & rw, "F" & rw).Copy sh3.Cells(Rows.Count, 1).End(xlUp)(2)
                sh2.Range("A" & fRw, "E" & fRw).Copy sh3.Cells(Rows.Count, 7).End(xlUp)(2)
            End If
    Next
Set sh1 = Nothing
Set sh2 = Nothing
Set sh3 = Nothing
Set rng = Nothing
Set fID = Nothing
End Sub
 
Upvote 0

Forum statistics

Threads
1,213,484
Messages
6,113,920
Members
448,533
Latest member
thietbibeboiwasaco

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