Copy non-contiguous cells from all workbooks in folder

D

dan dungan

Hi,

We're using excel 2000 on xp pro.

In a folder, we have hundreds of workbooks with data in cells A1, A3,
F9, I38, I44 on the first sheet of each workbook.

Using Ron DeBruin's sub Basic_Example_1 copies the data from the first
worksheet in each workbook, as I require, however, I don't know how
to get the data only the data from cells A1, A3, F9, I38, I44?


Thanks,

Dan Dungan


This code shown below sets the range in the the section--

With mybook.Worksheets(1)
Set sourceRange = .Range(A1, A3, F9, I38, I44)
End With
____________________________________________________

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 = "L:\My Documents\00-MASTERS"

'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, A3, F9, I38, I44)
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 = BaseWks.Cells(rnum, "B").
_

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
 
D

dan dungan

Thanks, Ron.

That works!

It turns out that the data is not always on the first sheet. I'm
working with workbooks created by another person who is no longer
here.

It appears there may be as many a 6 sheets in a workbook. I can run
the macro and change the sheet name or can you suggest a way to
collect this regardless of how many sheets are in each workbook?

Thanks again,

Dan
 
R

Ron de Bruin

Hi Dan

I see if I have time tomorrow to make a example for you.

To be sure you want the cells from each sheet that is in each workbook
Am I correct ?

Bed time now for me
 
D

dan dungan

Hi Ron,

My last reply doesn't seem to have gone through.

Thanks for your time and attention.

The procedure at http://www.rondebruin.nl/summary2.htm works.

However, the person who designed these worksheets used different
conventions over the years, and I need to look on each sheet in the
workbook. Please suggest how I might do that.

Thanks,
Dan
 
D

dan dungan

Hi Ron,

It would also be useful if I could capture the worksheet name for each
row.

Thanks,

Dan
 
R

Ron de Bruin

Hi Dan

Test this one for me

Sub Basic_Example_1_Test()
Dim MyPath As String, FilesInPath As String
Dim MyFiles() As String
Dim 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 sh As Worksheet, I As Integer, cell As Range

'Fill in the path\folder where the files are
MyPath = "L:\My Documents\00-MASTERS"

'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

For Each sh In mybook.Worksheets

On Error Resume Next
With sh
Set sourceRange = .Range("A1,A3,F9,I38,I44")
End With

If Err.Number > 0 Then
Err.Clear
Set sourceRange = Nothing
End If
On Error GoTo 0

If Not sourceRange Is Nothing Then
I = 3
'Copy the file name in column A
BaseWks.Cells(rnum, "A").Value = MyFiles(Fnum)
BaseWks.Cells(rnum, "B").Value = sh.Name

For Each cell In sourceRange.Areas

BaseWks.Cells(rnum, I).Value = cell.Value
I = I + 1

Next cell
rnum = rnum + 1
End If
Next sh
mybook.Close savechanges:=False
End If
Next Fnum
BaseWks.Columns.AutoFit
End If

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

dan dungan

Wow!

I don't know what else to say, except I must study this until I
understand it.

Thank you very much, Ron!

Dan
 

Ask a Question

Want to reply to this thread or ask your own question?

You'll need to choose a username for the site, which only take a couple of moments. After that, you can post your question and our members will help you out.

Ask a Question

Similar Threads


Top