Combine Lists Into Single Master List

Hantzisp

New Member
Joined
Apr 11, 2019
Messages
9
Greeting Everyone,

Long time lurker, first time poster. Thought I'd reach out for once. I understand VBA okay enough to figure out most issues on my own. I'm not a beginner, but I would't say I'm at a solid intermediate level either. I’m having trouble finding good code examples for this specific issue I'm trying to solve and thought I'd reach out. It’s regarding combining lists from separate workbooks into one master list. Here’s what I would like the code to do.

Step 1 - Combine 2 lists from 2 workbooks into 1 list.

Step 2 - Identify duplicates using the “ID” columns and sort with duplicates on top.

Step 3 – Change an alpha character in one of the duplicates to make it unique.

I've save and example spreadsheet to DropBox at the link below. It is an example of what I’m looking for. In the example, the worksheets “wbk1” & “wkb2” represents the two separate workbooks I wish to combine. The worksheet “Combined” represents the finished product I’m trying to achieve.

HTML:
https://www.dropbox.com/s/0rul5dusic5erwm/Example.xlsx?dl=0

Other thoughts:

The number of people on either of this list will change from month to month so a simple copy and paste code won’t do the trick [e.g. Range(“A2:E18”).copy]. The code needs to start at Row 2 on workbook1 of the workbooks and go down the Rows until there’s no more info, then copy and paste the list at the bottom of workbook2’s list thereby combining the two list.

Any help would be greatly appreciate and thanks in advance!
 

Excel Facts

Why does 9 mean SUM in SUBTOTAL?
It is because Sum is the 9th alphabetically in Average, Count, CountA, Max, Min, Product, StDev.S, StDev.P, Sum, VAR.S, VAR.P.
Screen shots for reference.



I couldn't edit my above post to add these screens in and remove the link to DB so just wanted to post this here for reference.
 
Upvote 0
Based on your file with the two sheets in the same book, how about
Code:
Sub Hantzisp()
   With Sheets("Combined")
      Sheets("Wkb1").Range("A1").CurrentRegion.Copy .Range("A1")
      Sheets("Wkb2").Range("A1").CurrentRegion.Offset(1).Copy .Range("A" & Rows.Count).End(xlUp).Offset(1)
      .Range("F2", .Range("A" & Rows.Count).End(xlUp).Offset(, 5)).Formula = "=countif(A:A,a2)"
      .Range("A1").CurrentRegion.Sort Key1:=.Range("F1"), Order1:=xlDescending, Key2:=.Range("A1") _
         , Order2:=xlAscending, Header:=xlYes, OrderCustom:=1, MatchCase:=False
      .Columns(6).Delete
   End With
End Sub
For parts 1 & 2
 
Upvote 0
Thanks, sir. The two sheets (wkb1, wkb2) are two separate Excel workbook files. My apologies for not making that clear. But your code is the right idea and works beautifully. I plan on running the code from a command button on a separate workbook I use to run my reports. When I click the command button, I’m trying to get it to open the 2 separate workbook files, capture the data from both and combined the data into one sheet. If I declare the workbooks and worksheets, I'm thinking I can open them. Here's what I'm testing right now

Code:
Dim wb1 As Workbook
Dim ws1 As Worksheet
Dim wb2 As Workbook
Dim ws2 As Worksheet
Dim cmbwb As Workbook
Dim cmbws As Worksheet


Set wb1 = Workbooks.Open("C:\Users\Hantzisp\Desktop\wkb1.xlsx")
Set ws1 = wb1.Sheets("Sheet1")  
Set wb2 = Workbooks.Open("C:\Users\Hantzisp\Desktop\wkb2.xlsx")
Set ws2 = wb2.Sheets("Sheet1")
Set cmbwb = Workbooks.Open("C:\Users\Hantzisp\Desktop\Combined.xlsx")
Set cmbws = cmbwb.Sheets("Sheet1")

This opens the workbooks for me, but I can't figure out how to alter your and combine code to grab the data from the files since they are in separate workbooks now.

I renamed the my testing worksheets in the workbooks to Sheet1 so I wouldn't have a workbook and worksheet with the same name.

Excel File 1 = wkb1
Excel File 2 = wkb2
Excel File 3 = Combined
 
Upvote 0
Try
Code:
Sub Hantzisp()
   Dim wb1 As Workbook
   Dim ws1 As Worksheet
   Dim wb2 As Workbook
   Dim ws2 As Worksheet
   Dim cmbwb As Workbook
   Dim cmbws As Worksheet
   
   
   Set wb1 = Workbooks.Open("C:\Users\Hantzisp\Desktop\wkb1.xlsx")
   Set ws1 = wb1.Sheets("Sheet1")
   Set wb2 = Workbooks.Open("C:\Users\Hantzisp\Desktop\wkb2.xlsx")
   Set ws2 = wb2.Sheets("Sheet1")
   Set cmbwb = Workbooks.Open("C:\Users\Hantzisp\Desktop\Combined.xlsx")
   Set cmbws = cmbwb.Sheets("Sheet1")
   With cmbws
      ws1.Range("A1").CurrentRegion.Copy .Range("A1")
      ws2.Range("A1").CurrentRegion.Offset(1).Copy .Range("A" & Rows.Count).End(xlUp).Offset(1)
      .Range("F2", .Range("A" & Rows.Count).End(xlUp).Offset(, 5)).Formula = "=countif(A:A,a2)"
      .Range("A1").CurrentRegion.Sort Key1:=.Range("F1"), Order1:=xlDescending, Key2:=.Range("A1") _
         , Order2:=xlAscending, Header:=xlYes, OrderCustom:=1, MatchCase:=False
      .Columns(6).Delete
   End With
End Sub
 
Upvote 0

Forum statistics

Threads
1,224,820
Messages
6,181,159
Members
453,021
Latest member
Justyna P

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