Macros to Merge Workbooks with Non-Contiguous Columns

shendik

New Member
Joined
Aug 22, 2011
Messages
15
Hello everybody! This is my first post on this forum. I am trying to consolidate many reports into one workbook for data analysis purposes.

I found the macro code pasted below on the internet and it works great to merge continuous columns from different workbooks placed in a folder into one workbook. But what I would like to do is only transfer certain columns from the different reports into the designated workbook. For example, column A, C, F, I, etc.

I have highlighted the appropriate line in red below. It works great if the range is just column A or column A:C, but how do I modify it to select column A, column C, and column I? I tried modifying the code but began running errors. Maybe it is just a simple syntax error. Please let me know. Thank you very much.

Macros Code

Sub MergeHorizontally()
Dim MyPath As String, FilesInPath As String
Dim MyFiles() As String
Dim SourceCcount As Long, FNum As Long
Dim mybook As Workbook, BaseWks As Worksheet
Dim sourceRange As Range, destrange As Range
Dim Cnum As Long, CalcMode As Long
' Change this to the path\folder location of the files.
MyPath = "C:\Documents and Settings\ksundar\Desktop\Practice"
' Add a slash at the end of path if needed.
If Right(MyPath, 1) <> "\" Then
MyPath = MyPath & "\"
End If
' If there are no Excel files in the folder, exit.
FilesInPath = Dir(MyPath & "*.xl*")
If FilesInPath = "" Then
MsgBox "No files found"
Exit Sub
End If
' Fill in the myFiles array with the list of Excel files in
' the search folder.
FNum = 0
Do While FilesInPath <> ""
FNum = FNum + 1
ReDim Preserve MyFiles(1 To FNum)
MyFiles(FNum) = FilesInPath
FilesInPath = Dir()
Loop
' Change the application properties.
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)
Cnum = 1
' Loop through all of the files in the myFiles array.
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
Set sourceRange = mybook.Worksheets(1).Range("A1:A1000")
If Err.Number > 0 Then
Err.Clear
Set sourceRange = Nothing
Else
' If the source range uses all of the rows
' then skip this file.
If sourceRange.rows.Count >= BaseWks.rows.Count Then
Set sourceRange = Nothing
End If
End If
On Error GoTo 0
If Not sourceRange Is Nothing Then
SourceCcount = sourceRange.Columns.Count
If Cnum + SourceCcount >= BaseWks.Columns.Count Then
MsgBox "There are not enough columns in the sheet."
BaseWks.Columns.AutoFit
mybook.Close savechanges:=False
GoTo ExitTheSub
Else
' Copy the file name in the first row.
With sourceRange
BaseWks.Cells(1, Cnum). _
Resize(, .Columns.Count).Value = MyFiles(FNum)
End With
' Set the destination range.
Set destrange = BaseWks.Cells(2, Cnum)
' Copy the values from the source range
' to the destination range.
With sourceRange
Set destrange = destrange. _
Resize(.rows.Count, .Columns.Count)
End With
destrange.Value = sourceRange.Value
Cnum = Cnum + SourceCcount
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
 
Last edited:

Excel Facts

Copy formula down without changing references
If you have =SUM(F2:F49) in F50; type Alt+' in F51 to copy =SUM(F2:F49) to F51, leaving the formula in edit mode. Change SUM to COUNT.
In addition to the issue described in the earlier post, I would also like to invite suggestions for calling specific worksheets from all the workbooks placed in a folder. In other words, I would like the macro to be able to copy data from a specific worksheet in all the workbooks placed in a folder. Please let me know. Thanks! :confused:
 
Upvote 0
Welcome to the board!

Your red line of code could look like this instead:

Rich (BB code):
Set sourceRange = mybook.Worksheets(1).Range("A1:A1000,C1:C1000")

For your second question, see here: http://www.mrexcel.com/forum/showthread.php?t=433931

Tai

edit: now I look at your code, you already have the "loop through a folder" part. I think what you need is just another change to the red line, like this:

Rich (BB code):
Set sourceRange = mybook.Worksheets("my worksheet name").Range("A1:A1000,C1:C1000")
 
Last edited:
Upvote 0
Thank you for your respone taigovinda. I tried the revised line your suggested. This resolved the issue of pulling data from the appropriate worksheet within the workbooks.

As for my original problem... It still persists. I had already tried "A1:A1000,C1:C1000" as you suggested but it does not pull data from two non-contiguous columns. If it is A1:C1000 instead, it pulls the data from columns A through C successfully, but doesn't pick multiple ranges. Do you think any other changes need to be made in other lines of the macro to accommodate multiple ranges? Thanks!
 
Upvote 0
You're right, for the non-contiguous range to work you would need to change some of the rest of the code. Try changing this:
Code:
SourceCcount = sourceRange.Columns.Count
If Cnum + SourceCcount >= BaseWks.Columns.Count Then
MsgBox "There are not enough columns in the sheet."
BaseWks.Columns.AutoFit
mybook.Close savechanges:=False
GoTo ExitTheSub
Else
' Copy the file name in the first row.
With sourceRange
BaseWks.Cells(1, Cnum). _
Resize(, .Columns.Count).Value = MyFiles(FNum)
End With
' Set the destination range.
Set destrange = BaseWks.Cells(2, Cnum)
' Copy the values from the source range
' to the destination range.
With sourceRange
Set destrange = destrange. _
Resize(.rows.Count, .Columns.Count)
End With
destrange.Value = sourceRange.Value
Cnum = Cnum + SourceCcount
End If

edit: accidentally posted... adjusted code will follow in another post
 
Last edited:
Upvote 0
Here's the edited code (that should have been posted at the bottom of #6:

Rich (BB code):
SourceCcount = 0
For Each rngArea In SourceRange.Areas
  SourceCcount = SourceCcount + rngArea.Columns.Count
Next
If Cnum + SourceCcount >= BaseWks.Columns.Count Then
MsgBox "There are not enough columns in the sheet."
BaseWks.Columns.AutoFit
mybook.Close savechanges:=False
GoTo ExitTheSub
Else
' Copy the file name in the first row.
With sourceRange
BaseWks.Cells(1, Cnum). _
Resize(, SourceCcount).Value = MyFiles(FNum)
End With
' Set the destination range.
Set destrange = BaseWks.Cells(2, Cnum)
' Copy the values from the source range
' to the destination range.
With sourceRange
Set destrange = destrange. _
Resize(.rows.Count, SourceCcount)
End With
sourceRange.copy
destrange.pastespecial paste:=xlvalues
application.cutcopymode=false 
Cnum = Cnum + SourceCcount
End If
 
Upvote 0
Hi,<?xml:namespace prefix = o ns = "urn:schemas-microsoft-com:eek:ffice:eek:ffice" /><o:p></o:p>
This is lingesh.<o:p></o:p>
I have read your post on (http://www.mrexcel.com/forum/showthread.php?t=573584) and your discussion is so useful for me to make a similar kind of automation. Your code is a very good starting point for combine multiple workbooks with non-adjacent columns.<o:p></o:p>
The available code combines data from multiple workbooks and populates it column wise (Merges horizontally) but i want to cluster them row –wise.<o:p></o:p>
I tried a lot to make it but end up with lots of bugs.<o:p></o:p>
Could you share your idea to manipulate the code, so that it will automate the data accumulation in row wise?<o:p></o:p>
<o:p></o:p>
Here is the code for your understanding.<o:p></o:p>
Expecting your positive reply.<o:p></o:p>

Sub MergeHorizontally()<o:p></o:p>
Dim MyPath As String, FilesInPath As String<o:p></o:p>
Dim MyFiles() As String<o:p></o:p>
Dim SourceCcount As Long, FNum As Long<o:p></o:p>
Dim mybook As Workbook, BaseWks As Worksheet<o:p></o:p>
Dim sourceRange As Range, destrange As Range<o:p></o:p>
Dim Cnum As Long, CalcMode As Long<o:p></o:p>
MyPath = "C "<o:p></o:p>
' Add a slash at the end of path if needed.<o:p></o:p>
If Right(MyPath, 1) <> "\" Then<o:p></o:p>
MyPath = MyPath & "\"<o:p></o:p>
End If<o:p></o:p>
FilesInPath = Dir(MyPath & "*.xl*")<o:p></o:p>
If FilesInPath = "" Then<o:p></o:p>
MsgBox "No files found"<o:p></o:p>
Exit Sub<o:p></o:p>
End If<o:p></o:p>
FNum = 0<o:p></o:p>
Do While FilesInPath <> ""<o:p></o:p>
FNum = FNum + 1<o:p></o:p>
ReDim Preserve MyFiles(1 To FNum)<o:p></o:p>
MyFiles(FNum) = FilesInPath<o:p></o:p>
FilesInPath = Dir()<o:p></o:p>
<?xml:namespace prefix = st1 ns = "urn:schemas-microsoft-com:eek:ffice:smarttags" /><st1:place w:st="on">Loop</st1:place><o:p></o:p>
With Application<o:p></o:p>
CalcMode = .Calculation<o:p></o:p>
.Calculation = xlCalculationManual<o:p></o:p>
.ScreenUpdating = False<o:p></o:p>
.EnableEvents = False<o:p></o:p>
End With<o:p></o:p>
Set BaseWks = Workbooks.Add(xlWBATWorksheet).Worksheets(1)<o:p></o:p>
Cnum = 1<o:p></o:p>
If FNum > 0 Then<o:p></o:p>
For FNum = LBound(MyFiles) To UBound(MyFiles)<o:p></o:p>
Set mybook = Nothing<o:p></o:p>
On Error Resume Next<o:p></o:p>
Set mybook = Workbooks.Open(MyPath & MyFiles(FNum))<o:p></o:p>
On Error GoTo 0<o:p></o:p>
If Not mybook Is Nothing Then<o:p></o:p>
On Error Resume Next<o:p></o:p>
Set sourceRange = mybook.Worksheets("my worksheet name").Range("A1:A1000,C1:C1000")<o:p></o:p>
If Err.Number > 0 Then<o:p></o:p>
Err.Clear<o:p></o:p>
Set sourceRange = Nothing<o:p></o:p>
Else<o:p></o:p>
If sourceRange.rows.Count >= BaseWks.rows.Count Then<o:p></o:p>
Set sourceRange = Nothing<o:p></o:p>
End If<o:p></o:p>
End If<o:p></o:p>
On Error GoTo 0<o:p></o:p>
If Not sourceRange Is Nothing Then<o:p></o:p>
SourceCcount = 0<o:p></o:p>
For Each rngArea In SourceRange.Areas<o:p></o:p>
SourceCcount = SourceCcount + rngArea.Columns.Count<o:p></o:p>
Next<o:p></o:p>
If Cnum + SourceCcount >= BaseWks.Columns.Count Then<o:p></o:p>
MsgBox "There are not enough columns in the sheet."<o:p></o:p>
BaseWks.Columns.AutoFit<o:p></o:p>
mybook.Close savechanges:=False<o:p></o:p>
GoTo ExitTheSub<o:p></o:p>
Else<o:p></o:p>
' Copy the file name in the first row.<o:p></o:p>
With sourceRange<o:p></o:p>
BaseWks.Cells(1, Cnum). _<o:p></o:p>
Resize(, SourceCcount).Value = MyFiles(FNum)<o:p></o:p>
End With<o:p></o:p>
' Set the destination range.<o:p></o:p>
Set destrange = BaseWks.Cells(2, Cnum)<o:p></o:p>
With sourceRange<o:p></o:p>
Set destrange = destrange. _<o:p></o:p>
Resize(.rows.Count, SourceCcount)<o:p></o:p>
End With<o:p></o:p>
sourceRange.copy<o:p></o:p>
destrange.pastespecial paste:=xlvalues<o:p></o:p>
application.cutcopymode=false <o:p></o:p>
Cnum = Cnum + SourceCcount<o:p></o:p>
End If<o:p></o:p>
End If<o:p></o:p>
mybook.Close savechanges:=False<o:p></o:p>
End If<o:p></o:p>
Next FNum<o:p></o:p>
BaseWks.Columns.AutoFit<o:p></o:p>
End If<o:p></o:p>
ExitTheSub:<o:p></o:p>
'Restore ScreenUpdating, Calculation and EnableEvents<o:p></o:p>
With Application<o:p></o:p>
.ScreenUpdating = True<o:p></o:p>
.EnableEvents = True<o:p></o:p>
.Calculation = CalcMode<o:p></o:p>
End With<o:p></o:p>
End Sub
 
Upvote 0

Forum statistics

Threads
1,216,160
Messages
6,129,215
Members
449,493
Latest member
JablesFTW

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