Back to jkp-ads.com |
Ron de Bruin
|
Ron de Bruin decided to remove all Windows Excel content from his website for personal reasons. If you want to know why, head over to rondebruin.nl.
Luckily, Ron was kind enough to allow me to publish all of his Excel content here.
Most of these pages are slightly outdated and may contain links that don 't work. Please inform me if you find such an error and I'll try to fix it.
Kind regards
Jan Karel Pieterse
Copy the code in a Standard module of your workbook, if you just
started with VBA see this page.
Where do I paste
the code that I find on the internet
Code Examples that use DIR
There are four basic
examples, 3 on this page and 4 in the example workbook:
1)
Merge a range from all workbooks in a folder (below each other)
2) Merge a range from every workbook you select (below each other)
3) Merge a range from all workbooks in a folder (next to
each other)
4) Merge a range from all workbooks in a
folder with AutoFilter
The code will create a new workbook for you
with the data from all workbooks with in column A or in row 1 the file name
of the data in that row or column. It is up to you if you save the workbook.
The examples below are only working for one folder, there is no option for subfolders. But In the download section of this page you find a download with code with a option for subfolders and more. If you want all the options in a nice user interface then try my RDBMerge add-in, you find a link to this add-in also there.
Note: The workbook with the code must be outside the
merge folder
Tip 1: Useful Workbooks.Open arguments
Set mybook = Workbooks.Open(MyPath &
MyFiles(Fnum), _
Password:="ron", WriteResPassword:="ron",
UpdateLinks:=0)
If your workbooks are protected you can us
this in the Workbooks.Open arguments
Password:="ron” and WriteResPassword:="ron"
If you have links
in your workbook this (UpdateLinks:=0)
will
avoid the message do you want to update the links or not "0 Doesn't update
any references"
Use 3 instead of 0 if you want to update the links.
See the VBA help for more information about the Workbooks.Open arguments
Tip 2: Merge from all Files with a name that start with
for example week, use this then
FilesInPath =
Dir(MyPath & "week*.xl*")
Tip 3: Copy values
and formats
the macro examples below will copy only the values, if
you want to copy the formats also replace :
With SourceRange Set destrange = destrange. _ Resize(.Rows.Count, .Columns.Count) End With destrange.Value = SourceRange.Value
With
SourceRange.Copy With destrange .PasteSpecial xlPasteValues .PasteSpecial xlPasteFormats Application.CutCopyMode = False End With
Before you restore ScreenUpdating, Calculation and EnableEvents also add this line
Application.Goto BaseWks.Cells(1)
Download a zip file with a workbook with the code from this page to test
the examples:
Download
MergeDirExamples.zip
Or download this file with FSO code that have a option to include subfolders and a option to merge data from all worksheets in each workbook. There is more code in this file but the macro we call is easier to edit. Download MergeFSOExamples.zip, you can also download the FSO code as TXT file.
Or if you want all the options in a nice user interface check ou this
add-in :
RDBMerge, Excel Merge Add-in
for Excel for Windows
There are a few things you must change before you can run the code
Fill in the path to the folder
MyPath =
"C:\Users\Ron\test"
I use the first worksheet of each workbook
in my example (index 1). Change the worksheet index or fill in a sheet name:
mybook.Worksheets("YourSheetName"). And change
the range A1:C1 to your range
With mybook.Worksheets(1) Set SourceRange = .Range("A1:C1") End With
If you want to copy all cells from the worksheet or from A2 till the last cell on the worksheet.Then replace the code above with this
With mybook.Worksheets(1)
FirstCell = "A2"
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
Add also this dim line at the top of the macro
Dim FirstCell As String
Note: the code above use the function
RDB_Last, copy this function also in your code module if you use it. You
find the function in the last section of this page.
Fill in the first
cell here and the code will find the last cell on the worksheet for you.
FirstCell = "A2"
Sub Basic_Example_1() 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 'Fill in the path\folder where the files are MyPath = "C:\Users\Ron\test" '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 & "*.xl*") 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 '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(1) Set sourceRange = .Range("A1:C1") 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 'Copy the file name in column A With sourceRange BaseWks.cells(rnum, "A"). _ Resize(.Rows.Count).Value = MyFiles(Fnum) End With '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
This code example will do the same as the example above only when you run
the code you are able to select the files you want to merge.
Fill in
the path to the folder
ChDirNet "C:\Users\Ron\test"
And change the sheet and range to yours (see first example). It
is also possible to set the start folder with ChDrive and ChDir but I choose
to use the SetCurrentDirectoryA function in this example because it also is
working with network folders.
Note: Copy all code below in a normal
module of your workbook
#If VBA7 Then Declare PtrSafe Function SetCurrentDirectoryA Lib _ "kernel32" (ByVal lpPathName As String) As Long #Else Declare Function SetCurrentDirectoryA Lib _ "kernel32" (ByVal lpPathName As String) As Long #End If Sub ChDirNet(szPath As String) SetCurrentDirectoryA szPath End Sub Sub Basic_Example_2() Dim MyPath 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 SaveDriveDir As String Dim FName As Variant 'Change ScreenUpdating, Calculation and EnableEvents With Application CalcMode = .Calculation .Calculation = xlCalculationManual .ScreenUpdating = False .EnableEvents = False End With SaveDriveDir = CurDir ChDirNet "C:\Users\Ron\test" FName = Application.GetOpenFilename(filefilter:="Excel Files (*.xl*), *.xl*", _ MultiSelect:=True) If IsArray(FName) Then 'Add a new workbook with one sheet Set BaseWks = Workbooks.Add(xlWBATWorksheet).Worksheets(1) rnum = 1 'Loop through all files in the array(myFiles) For Fnum = LBound(FName) To UBound(FName) Set mybook = Nothing On Error Resume Next Set mybook = Workbooks.Open(FName(Fnum)) On Error GoTo 0 If Not mybook Is Nothing Then On Error Resume Next With mybook.Worksheets(1) Set sourceRange = .Range("A1:C1") 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 'Copy the file name in column A With sourceRange BaseWks.Cells(rnum, "A"). _ Resize(.Rows.Count).Value = FName(Fnum) End With '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 ChDirNet SaveDriveDir End Sub
This example will past the data next to each other. In column A you see
the data from the first workbook and in Column B the data from the next and
in.....
There are a few things you must change before you can run the
code
Fill in the path to the folder
MyPath =
"C:\Users\Ron\test"
I use the first sheet of each workbook in
my example (index 1). Change the sheet index or fill in a sheet name:
mybook.Worksheets("YourSheetName"). And change
the range A1:A10 to your range.
Set sourceRange
= mybook.Worksheets(1).Range("A1:A10")
Sub Basic_Example_3() 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 'Fill in the path\folder where the files are MyPath = "C:\Users\Ron\test" '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 & "*.xl*") 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) Cnum = 1 '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 Set sourceRange = mybook.Worksheets(1).Range("A1:A10") If Err.Number > 0 Then Err.Clear Set sourceRange = Nothing Else 'if SourceRange use all 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 "Sorry 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 destrange Set destrange = BaseWks.cells(2, Cnum) '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 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
You find this macro in the workbook that you can download on this page.This example will filter a range on a worksheet in every workbook in the folder and copy the filter results to a new workbook. There are five code lines that you must change before you run the code(see the code in the VBA editor)
Function RDB_Last(choice As Integer, rng As Range)
'Ron de Bruin, 5 May 2008
' 1 = last row
' 2 = last column
' 3 = last cell
Dim lrw As Long
Dim lcol As Integer
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
End Function