PDA

View Full Version : Merge Workbooks to Master Workbook



donb1337
09-24-2013, 08:52 PM
Hi guys,

at the moment I'm trying to consolidate four Workbooks to a Master Workbook.

The four Workbooks I want to merge have the same table structure but except the "Project Number" they have almost different data in their columns.

What I want to do is creating a Master Workbook in which all the Projects are listed once with the information of all four Lists.


I think I know what to do but I don't know how to do it...


While consolidating the data should be checked whether it is already in the Master Workbook or not:
If yes the Macro should copy the adding data in the existing Project row and there in the correct column.
If not the Macro should create a new row for the Project. <- So there should be something like "+1".

I think the problem could be to define in which column what information should be copied.
At the moment I already set header in the Master Workbook. Does that makes sense or is there a smarter way to simplify it?
The point is that I should be able to control which data will be copied in which column.

To make it easier for you to understand what I'm talking about I created an Example file in which the four Workbooks plus the Master Workbook are and attached it.


Any kind of help is really appreciated! Thanks in advance!

Excel Fox
09-24-2013, 09:37 PM
don, I see only 1 workbook attached. Do you mean that you've got 5 sheets in all in that one workbook?

Excel Fox
09-24-2013, 09:58 PM
OK, apparently, you've clarified that in the attachment. Your sheets actually represent the individual workbooks.

donb1337
09-25-2013, 08:09 AM
Yes exactly. Do you have any idea or advice for me Excel Fox?

Cheers!

donb1337
09-25-2013, 12:29 PM
This is the code I'm working with. There are no errors but something goes wrong with the copying and I have no idea what.


Sub MergeWorkbooks ()
Dim choice As Integer, rng As Range
Dim lrw As Long
Dim lcol As Integer

' Case 1 = last row
' Case 2 = last column
' Case 3 = last cell

Select Case choice

Case 1:
On Error Resume Next
RDB_Last = rng.Find(What:="*", _
after:=rng.Cells(1), _
Lookat:=xlPart, _
LookIn:=xlFormulas, _
SearchOrder:=xlByRows, _
SearchDirection:=xlPrevious, _
MatchCase:=False).Row
On Error GoTo 0

Case 2:
On Error Resume Next
RDB_Last = rng.Find(What:="*", _
after:=rng.Cells(1), _
Lookat:=xlPart, _
LookIn:=xlFormulas, _
SearchOrder:=xlByColumns, _
SearchDirection:=xlPrevious, _
MatchCase:=False).Column
On Error GoTo 0

Case 3:
On Error Resume Next
lrw = rng.Find(What:="*", _
after:=rng.Cells(1), _
Lookat:=xlPart, _
LookIn:=xlFormulas, _
SearchOrder:=xlByRows, _
SearchDirection:=xlPrevious, _
MatchCase:=False).Row
On Error GoTo 0

On Error Resume Next
lcol = rng.Find(What:="*", _
after:=rng.Cells(1), _
Lookat:=xlPart, _
LookIn:=xlFormulas, _
SearchOrder:=xlByColumns, _
SearchDirection:=xlPrevious, _
MatchCase:=False).Column
On Error GoTo 0

On Error Resume Next
RDB_Last = rng.Parent.Cells(lrw, lcol).Address(False, False)
If Err.Number > 0 Then
RDB_Last = rng.Cells(1).Address(False, False)
Err.Clear
End If
On Error GoTo 0

End Select



' MERGE LISTS
' --------------------------------------------------------------


Dim MyPath As String, FilesInPath As String
Dim MyFiles() As String
Dim SourceRcount As Long, Fnum As Long
Dim mybook As Workbook, BaseWks As Worksheet
Dim sourceRange As Range, destrange As Range
Dim rnum As Long, CalcMode As Long
Dim FirstCell As String

'Fill in the path\folder where the files are
MyPath = "C:\xyz\Project lists"

'Add a slash at the end if the user forget it
If Right(MyPath, 1) <> "\" Then
MyPath = MyPath & "\"
End If

'If there are no Excel files in the folder exit the sub
FilesInPath = Dir(MyPath & "*.xls*")
If FilesInPath = "" Then
MsgBox "No files found"
Exit Sub
End If

'Fill the array(myFiles)with the list of Excel files in the folder
Fnum = 0
Do While FilesInPath <> ""
Fnum = Fnum + 1
ReDim Preserve MyFiles(1 To Fnum)
MyFiles(Fnum) = FilesInPath
FilesInPath = Dir()
Loop

'Change ScreenUpdating, Calculation and EnableEvents
With Application
CalcMode = .Calculation
.Calculation = xlCalculationManual
.ScreenUpdating = False
.EnableEvents = False
End With

'Add a new workbook with one sheet
Set BaseWks = Workbooks.Add(xlWBATWorksheet).Worksheets(1)
rnum = 1
ActiveWorkbook.SaveAs "C:\xyz\MasterProjectList.xlsx"

' Set header
Cells(1, 1).Value = "Project Number"
Cells(1, 2).Value = "Project Description 1"
Cells(1, 3).Value = "Project Description 2"
Cells(1, 4).Value = "Project Description 3"
Cells(1, 5).Value = "Project Description 4"
Cells(1, 6).Value = "Priority Status"
Cells(1, 7).Value = "Process approval status"
Cells(1, 8).Value = "Project Manager"
Cells(1, 9).Value = "Planning responsible"
Cells(1, 10).Value = "Customer"
Cells(1, 11).Value = "Profit Center"


'Loop through all files in the array(myFiles)
If Fnum > 0 Then
For Fnum = LBound(MyFiles) To UBound(MyFiles)
Set mybook = Nothing
On Error Resume Next
Set mybook = Workbooks.Open(MyPath & MyFiles(Fnum))
On Error GoTo 0

If Not mybook Is Nothing Then

On Error Resume Next

With mybook.Worksheets("SpecificList")
FirstCell = "A1"
Set sourceRange = .Range(FirstCell & ":" & RDB_Last(3, .Cells))
'Test if the row of the last cell >= then the row of the FirstCell
If RDB_Last(1, .Cells) < .Range(FirstCell).Row Then
Set sourceRange = Nothing
End If
End With

If Err.Number > 0 Then
Err.Clear
Set sourceRange = Nothing
Else
'if SourceRange use all columns then skip this file
If sourceRange.Columns.Count >= BaseWks.Columns.Count Then
Set sourceRange = Nothing
End If
End If
On Error GoTo 0

If Not sourceRange Is Nothing Then

SourceRcount = sourceRange.Rows.Count

If rnum + SourceRcount >= BaseWks.Rows.Count Then
MsgBox "Sorry there are not enough rows in the sheet"
BaseWks.Columns.AutoFit
mybook.Close savechanges:=False
GoTo ExitTheSub
Else

'Set the destrange
Set destrange = BaseWks.Range("B" & rnum)

'we copy the values from the sourceRange to the destrange
With sourceRange
Set destrange = destrange. _
Resize(.Rows.Count, .Columns.Count)
End With
destrange.Value = sourceRange.Value

rnum = rnum + SourceRcount
End If
End If
mybook.Close savechanges:=False
End If

Next Fnum
BaseWks.Columns.AutoFit
End If

ExitTheSub:
'Restore ScreenUpdating, Calculation and EnableEvents
With Application
.ScreenUpdating = True
.EnableEvents = True
.Calculation = CalcMode
End With
End Sub

Any ideas guys?

Cheers!

Excel Fox
09-26-2013, 08:21 PM
Don, took a while, but here's the code you need



Option Explicit

Sub Consolidate()

Const clngWorkbooksToConsolidate As Long = 4
Dim var(1 To clngWorkbooksToConsolidate) As Variant
Dim varColIndex(1 To clngWorkbooksToConsolidate) As Variant
Dim varColHeader As Variant
Dim lngLoop As Long, lngRow As Long, lngCol As Long, lngIndex As Long
Dim objDic As Object
Dim strFilesFolder As String
Dim strFile As String

With Application.FileDialog(msoFileDialogFilePicker)
.AllowMultiSelect = True
.Filters.Clear
.Filters.Add "Excel Files", "*.xlsx", 1
.Show
Application.ScreenUpdating = False
If .SelectedItems.Count = clngWorkbooksToConsolidate Then
For lngLoop = 1 To clngWorkbooksToConsolidate
With Workbooks.Open(.SelectedItems(lngLoop), , False)
var(lngLoop) = .Sheets(1).Cells(1).CurrentRegion.Value2
.Close 0
End With
Next lngLoop
Else
MsgBox clngWorkbooksToConsolidate & " workbooks were not selected. Program will now exit", vbOKOnly + vbInformation, ""
GoTo EndSub
End If
End With
Set objDic = CreateObject("Scripting.Dictionary")
varColHeader = Array("Project Number", "Project Description 1", "Project Description 2", "Project Description 3", "Project Description 4", "Priority Status", "Process approval status", "Project Manager", "Planning responsible", "Customer", "Profit Center")
For lngLoop = LBound(varColHeader, 1) To UBound(varColHeader, 1)
objDic.Item(varColHeader(lngLoop)) = 0
Next lngLoop
For lngLoop = 1 To clngWorkbooksToConsolidate
For lngCol = LBound(var(lngLoop), 2) To UBound(var(lngLoop), 2)
objDic.Item(var(lngLoop)(1, lngCol)) = 0
Next lngCol
Next lngLoop
varColHeader = objDic.keys
objDic.RemoveAll
For lngLoop = 1 To clngWorkbooksToConsolidate
For lngRow = 1 + LBound(var(lngLoop)) To UBound(var(lngLoop))
objDic.Item(var(lngLoop)(lngRow, 1)) = 0
Next lngRow
Next lngLoop
With ThisWorkbook.Sheets("Master Workbook")
.UsedRange.ClearContents
.Cells(1).Resize(, 1 + UBound(varColHeader)).Value = varColHeader
.Cells(2, 1).Resize(objDic.Count).Value = Application.Transpose(objDic.keys)
For lngIndex = 1 To clngWorkbooksToConsolidate
For lngCol = 1 + LBound(var(lngIndex), 2) To UBound(var(lngIndex), 2)
For lngLoop = 2 To 1 + UBound(varColHeader)
If var(lngIndex)(1, lngCol) = .Cells(1, lngLoop).Value Then
varColIndex(lngIndex) = varColIndex(lngIndex) & lngLoop & "|"
End If
Next lngLoop
Next lngCol
Next lngIndex
For lngLoop = 1 To clngWorkbooksToConsolidate
For lngIndex = 2 To objDic.Count
For lngRow = 2 To UBound(var(lngLoop))
If .Cells(lngIndex, 1).Value = var(lngLoop)(lngRow, 1) Then
For lngCol = LBound(Split(varColIndex(lngLoop), "|")) To UBound(Split(varColIndex(lngLoop), "|")) - 1
.Cells(lngRow, CLng(Split(varColIndex(lngLoop), "|")(lngCol))).Value = var(lngLoop)(lngRow, 2 + lngCol)
Next lngCol
End If
Next lngRow
Next lngIndex
Next lngLoop
.UsedRange.Sort Key1:=.Cells(1), Order1:=xlAscending, Header:=xlYes
End With
Erase var
Erase varColHeader
Erase varColIndex
EndSub:
Application.ScreenUpdating = True
Set objDic = Nothing

End Sub


I've also attached the workbook with the code. Just press CTRL+SHIFT+R (I've assigned that shortcut to the macro). It will then ask for the 4 workbooks to be selected. Select all 4, and click OK.

Let me know if you face any problem

donb1337
09-26-2013, 09:16 PM
Thank you so much for taking the time to reply, I really appreciate your help
Excel Fox. I will try the code asap and inform you how it went.

Cheers!