Data Extraction Macro Help

Exc123

New Member
Joined
Apr 5, 2006
Messages
38
Hi, I'm pretty new at the whole macro process and I'm attempting to work with the code pasted below. The code below is doing exactly what I need it to save for a few tweaks. However, I would like to set up within the excel worksheet an area for inputs for the file folder location for my workbooks, the name of the worksheet containing the range and the to be copied range for users that don't understand VBA (bolded within the code). In addition, I'd like the pasted values to maintain its formatting. Appreciate any help that anyone can provide.

Rich (BB code):
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\Documents\Excel"

    '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 = ActiveWorkbook.Worksheets.Add
        BaseWks.Name = Format(Now, "mm-yy") & " Data Dump"
    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("Compare").Range("D2:D21")

                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
 

Excel Facts

Bring active cell back into view
Start at A1 and select to A9999 while writing a formula, you can't see A1 anymore. Press Ctrl+Backspace to bring active cell into view.
Would you rather prompt the user to select the Folder from a dialog?

Code:
    [COLOR="Green"]' Prompt user to select a folder[/COLOR]
    With Application.FileDialog(msoFileDialogFolderPicker)
        .InitialFileName = "C:\Temp\"               [COLOR="Green"]' Default path[/COLOR]
        .Title = "Please Select a Folder"
        .ButtonName = "Select Folder"
        .AllowMultiSelect = False
        .Show
        If .SelectedItems.Count = 0 Then Exit Sub  [COLOR="Green"] ' User clicked cancel[/COLOR]
        MyPath = .SelectedItems.Item(1) & "\"
    End With
 
Upvote 0
Would you rather prompt the user to select the Folder from a dialog?

Code:
    [COLOR="Green"]' Prompt user to select a folder[/COLOR]
    With Application.FileDialog(msoFileDialogFolderPicker)
        .InitialFileName = "C:\Temp\"               [COLOR="Green"]' Default path[/COLOR]
        .Title = "Please Select a Folder"
        .ButtonName = "Select Folder"
        .AllowMultiSelect = False
        .Show
        If .SelectedItems.Count = 0 Then Exit Sub  [COLOR="Green"] ' User clicked cancel[/COLOR]
        MyPath = .SelectedItems.Item(1) & "\"
    End With

Very nice and I do like it. For the time being and in case anyone was curious I had changed my original code to check an input cell for the file name. Your solution is much easier though.

Rich (BB code):
    'Fill in the path\folder where the files are
    MyPath = Sheets("Input").Range("c2")

I'm still trying to think through the worksheet name and range aspects, but this is great!
 
Upvote 0
Do you want to prompt the user to select a different sheet and range for each workbook in the folder, or prompt them for one sheet name and range and use that for all workbooks in the folder?
 
Upvote 0
Do you want to prompt the user to select a different sheet and range for each workbook in the folder, or prompt them for one sheet name and range and use that for all workbooks in the folder?

The latter is what I had originally wanted as I'm new to macros and was trying to stay simple. However, the ability to decide which worksheet and range from any workbook within the folder sounds a lot more dynamic than what I had originally planned and seems like it would be the better option in the long run.
 
Upvote 0
Red code is what was changed from your original code.


Code:
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

    [COLOR="Green"]' Prompt user to select a folder[/COLOR]
[COLOR="Red"]    With Application.FileDialog(msoFileDialogFolderPicker)
        .InitialFileName = "C:\Temp\"               ' Default path
        .Title = "Please Select a Folder"
        .ButtonName = "Select Folder"
        .AllowMultiSelect = False
        .Show
        If .SelectedItems.Count = 0 Then Exit Sub   ' User clicked cancel
        MyPath = .SelectedItems.Item(1) & "\"
    End With[/COLOR]
    
    '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
        [COLOR="Red"]'.ScreenUpdating = False[/COLOR]
        .EnableEvents = False
    End With

    'Add a new workbook with one sheet
    Set BaseWks = ActiveWorkbook.Worksheets.Add
        BaseWks.Name = Format(Now, "mm-yy") & " Data Dump"
    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
[COLOR="Green"]''                Set sourceRange = mybook.Worksheets("Compare").Range("D2:D21")
                ' Prompt user to select a range[/COLOR]
[COLOR="Red"]                Set sourceRange = Application.InputBox("Select worksheet and cell range.", "Range Selection", Type:=8)[/COLOR]
                
                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
                        
                        [COLOR="Green"]' Copy cells with formatting[/COLOR]
                        [COLOR="Red"]sourceRange.Copy Destination:=destrange[/COLOR]
                        [COLOR="Green"]'destrange.Value = sourceRange.Value[/COLOR]

                        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

For a self proclaimed noob, you did a really nice job writing this. It was clean and easy to read.
 
Last edited:
Upvote 0
Red code is what was changed from your original code.


Code:
Sub Basic_Example_3()
                        [COLOR="Green"]' Copy cells with formatting[/COLOR]
                        [COLOR="Red"]sourceRange.Copy Destination:=destrange[/COLOR]
                        [COLOR="Green"]'destrange.Value = sourceRange.Value[/COLOR]

For a self proclaimed noob, you did a really nice job writing this. It was clean and easy to read.

Thanks AF! I wish I could take credit, but I've pulled most of the code together from this board among others. I did have one follow up on the quoted code, is there an ability to have it paste values and keep the formatting?

Greatly appreciate all of your help!
 
Upvote 0
Un-comment your original copy line.

Code:
  sourceRange.Copy Destination:=destrange [COLOR="Green"]' Copy everything[/COLOR]
  destrange.Value = sourceRange.Value     [COLOR="Green"]' Overwrite formulas with values[/COLOR]
 
Upvote 0

Forum statistics

Threads
1,224,612
Messages
6,179,890
Members
452,948
Latest member
Dupuhini

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