+ Reply to Thread
Results 1 to 20 of 20

Importing data from multiple files to new file

Hybrid View

  1. #1
    Registered User
    Join Date
    11-08-2012
    Location
    Wisconsin
    MS-Off Ver
    Excel 2010
    Posts
    41

    Importing data from multiple files to new file

    Hi all. I am trying to import data from multiple spreadsheets to a new file. I put all of my files in one folder. Each file is exactly the same as far as where the data is. I want the data in the new file to be in a nice clean line by line format. The multiple files have data all over the place.

    See example: (Attached File)

    I can make my own headers so I would like to keep the A1-Z1 row empty in the new file so we should start populating data with B1

    So in short I want to make information on the first file it pulls in to go on A2 B2 C2 .........ETC all the way across
    and the next file to go on A3 B3 B3.........ETC

    Thanks in advance for your help.
    Attached Files Attached Files

  2. #2
    Forum Contributor arlu1201's Avatar
    Join Date
    09-09-2011
    Location
    Bangalore, India
    MS-Off Ver
    Excel 2003 & 2007
    Posts
    19,166

    Re: Importing data from multiple files to new file

    You will need to specify what data goes where.
    If I have helped, Don't forget to add to my reputation (click on the star below the post)
    Don't forget to mark threads as "Solved" (Thread Tools->Mark thread as Solved)
    Use code tags when posting your VBA code: [code] Your code here [/code]

  3. #3
    Registered User
    Join Date
    11-08-2012
    Location
    Wisconsin
    MS-Off Ver
    Excel 2010
    Posts
    41

    Re: Importing data from multiple files to new file

    Ive been playing with this script:
    Sub MergeAllWorkbooks()
        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:\temp1"
    
        '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("D4")
                    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

  4. #4
    Registered User
    Join Date
    11-08-2012
    Location
    Wisconsin
    MS-Off Ver
    Excel 2010
    Posts
    41

    Re: Importing data from multiple files to new file

    I see where is has the range to copy
                    With mybook.Worksheets(1)
                        Set sourceRange = .Range("D4")
                    End With
    I also understand that in the code its going to paste to the "B" coulumn
                            '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)
    But the only thing I cant figure out is how to do this many times over in the script.

  5. #5
    Registered User
    Join Date
    11-08-2012
    Location
    Wisconsin
    MS-Off Ver
    Excel 2010
    Posts
    41

    Re: Importing data from multiple files to new file

    D4 Would go in the B Column
    D5 Would go in the C Column
    D5 Would go in the D Column
    D6 Would go in the E Column
    D7 Would go in the F Column
    D8 Would go in the g Column

  6. #6
    Registered User
    Join Date
    11-08-2012
    Location
    Wisconsin
    MS-Off Ver
    Excel 2010
    Posts
    41

    Re: Importing data from multiple files to new file

    I need to move about 20 cells total

  7. #7
    Forum Contributor arlu1201's Avatar
    Join Date
    09-09-2011
    Location
    Bangalore, India
    MS-Off Ver
    Excel 2003 & 2007
    Posts
    19,166

    Re: Importing data from multiple files to new file

    Ok, all you need to tell me is which cell of your source file goes where in the master file and i can help you with the code.

    Either you put out the list here or attach a sheet with the info.

  8. #8
    Forum Contributor arlu1201's Avatar
    Join Date
    09-09-2011
    Location
    Bangalore, India
    MS-Off Ver
    Excel 2003 & 2007
    Posts
    19,166

    Re: Importing data from multiple files to new file

    So you will need to specify all the 20 here, otherwise i wouldnt know which goes where.

  9. #9
    Registered User
    Join Date
    11-08-2012
    Location
    Wisconsin
    MS-Off Ver
    Excel 2010
    Posts
    41

    Re: Importing data from multiple files to new file

    I am assuming that if you map out the ones I gave you and you told me which parts to copy and paste I can save you some time? Otherwise my pleasure. Let me know.

  10. #10
    Forum Contributor arlu1201's Avatar
    Join Date
    09-09-2011
    Location
    Bangalore, India
    MS-Off Ver
    Excel 2003 & 2007
    Posts
    19,166

    Re: Importing data from multiple files to new file

    The reason i asked you for the list, is - sometimes we dont have to specify each cell, if they are consecutive or can be transposed, the macro can be designed that way.

  11. #11
    Registered User
    Join Date
    11-08-2012
    Location
    Wisconsin
    MS-Off Ver
    Excel 2010
    Posts
    41

    Re: Importing data from multiple files to new file

    D4 Would go in the B Column
    D5 Would go in the C Column
    D5 Would go in the D Column
    D6 Would go in the E Column
    D7 Would go in the F Column
    D8 Would go in the G Column
    N4 Would go in the H Column
    N5 Would go in the I Column
    N6 Would go in the J Column
    N7 Would go in the K Column
    N8 Would go in the L Column
    N9 Would go in the M Column
    N10 Would go in the N Column
    N11 Would go in the O Column
    RANGE A20:N20 Would go in the P Column
    RANGE A21:N21 Would go in the Q Column
    RANGE A22:N22 Would go in the R Column
    RANGE A23:N23 Would go in the S Column
    J29 Would go in the T Column
    L69 Would go in the U Column
    M69 Would go in the V Column
    O69 Would go in the W Column
    P69 Would go in the X Column
    D92 Would go in the Y Column

  12. #12
    Registered User
    Join Date
    11-08-2012
    Location
    Wisconsin
    MS-Off Ver
    Excel 2010
    Posts
    41

    Re: Importing data from multiple files to new file

    OK Ill tell you..Give me a moment please.

  13. #13
    Forum Contributor arlu1201's Avatar
    Join Date
    09-09-2011
    Location
    Bangalore, India
    MS-Off Ver
    Excel 2003 & 2007
    Posts
    19,166

    Re: Importing data from multiple files to new file

    2 pointers -

    RANGE A20:N20 Would go in the P Column
    RANGE A21:N21 Would go in the Q Column
    RANGE A22:N22 Would go in the R Column
    RANGE A23:N23 Would go in the S Columns
    You want multiple columns to be copied into 1 column. How do you want this to be done? Should i use any data separator?

    Also,
    D5 Would go in the C Column
    D5 Would go in the D Column
    You want D5 to go both into C and D columns?

  14. #14
    Registered User
    Join Date
    11-08-2012
    Location
    Wisconsin
    MS-Off Ver
    Excel 2010
    Posts
    41

    Re: Importing data from multiple files to new file

    The D5 was a typo. Im sorry I typed it twice. As far as the multiple cells...just jam them each all into one column please.

  15. #15
    Forum Contributor arlu1201's Avatar
    Join Date
    09-09-2011
    Location
    Bangalore, India
    MS-Off Ver
    Excel 2003 & 2007
    Posts
    19,166

    Re: Importing data from multiple files to new file

    Quote Originally Posted by agengler11 View Post
    The D5 was a typo. Im sorry I typed it twice. As far as the multiple cells...just jam them each all into one column please.
    What should go into column D?

  16. #16
    Forum Contributor arlu1201's Avatar
    Join Date
    09-09-2011
    Location
    Bangalore, India
    MS-Off Ver
    Excel 2003 & 2007
    Posts
    19,166

    Re: Importing data from multiple files to new file

    What should be the separator for the data?

  17. #17
    Registered User
    Join Date
    11-08-2012
    Location
    Wisconsin
    MS-Off Ver
    Excel 2010
    Posts
    41

    Re: Importing data from multiple files to new file

    Quote Originally Posted by arlu1201 View Post
    What should be the separator for the data?
    Please use a colon ":"

  18. #18
    Registered User
    Join Date
    11-08-2012
    Location
    Wisconsin
    MS-Off Ver
    Excel 2010
    Posts
    41

    Re: Importing data from multiple files to new file

    Can you move everything up a letter? If not you can leave blank.

  19. #19
    Forum Contributor arlu1201's Avatar
    Join Date
    09-09-2011
    Location
    Bangalore, India
    MS-Off Ver
    Excel 2003 & 2007
    Posts
    19,166

    Re: Importing data from multiple files to new file

    Try this code - put it in a blank workbook which is your summary book.
    Option Explicit
    
    Sub cons_data()
    Dim Master As Workbook
    Dim sourceBook As Workbook
    Dim sourceData As Worksheet
    Dim CurrentFileName As String
    Dim myPath As String
    Dim lastrow As Long, i As Long, lrow As Long
    
    Application.ScreenUpdating = False
    Application.DisplayAlerts = False
    
    'The folder containing the files to be recap'd
    myPath = "B:\Test"
    
    'Finds the name of the first file of type .xls in the current directory
    CurrentFileName = Dir(myPath & "\*.xlsx")
    
    'Create a workbook for the recap report
    Set Master = ThisWorkbook
    
    Do
        Workbooks.Open (myPath & "\" & CurrentFileName)
        Set sourceBook = Workbooks(CurrentFileName)
        Set sourceData = sourceBook.Worksheets(1)
        
            With sourceData
                lastrow = Master.Worksheets(1).Range("B" & Rows.Count).End(xlUp).Row
                Master.Worksheets(1).Range("B" & lastrow + 1).Value = .Range("D4").Value
                Master.Worksheets(1).Range("C" & lastrow + 1).Value = .Range("D5").Value
                .Range("D6:D8").Copy
                Master.Worksheets(1).Range("D" & lastrow + 1).PasteSpecial Paste:=xlPasteValues, Transpose:=True
                .Range("N4:N11").Copy
                Master.Worksheets(1).Range("G" & lastrow + 1).PasteSpecial Paste:=xlPasteValues, Transpose:=True
                For i = 1 To 14
                    Master.Worksheets(1).Range("O" & lastrow + 1).Value = Master.Worksheets(1).Range("O" & lastrow + 1).Value & ":" & .Cells(20, i).Value
                    Master.Worksheets(1).Range("P" & lastrow + 1).Value = Master.Worksheets(1).Range("P" & lastrow + 1).Value & ":" & .Cells(21, i).Value
                    Master.Worksheets(1).Range("Q" & lastrow + 1).Value = Master.Worksheets(1).Range("Q" & lastrow + 1).Value & ":" & .Cells(22, i).Value
                    Master.Worksheets(1).Range("R" & lastrow + 1).Value = Master.Worksheets(1).Range("R" & lastrow + 1).Value & ":" & .Cells(23, i).Value
                Next i
                Master.Worksheets(1).Range("S" & lastrow + 1).Value = .Range("J29").Value
                Master.Worksheets(1).Range("T" & lastrow + 1).Value = .Range("L69").Value
                Master.Worksheets(1).Range("U" & lastrow + 1).Value = .Range("M69").Value
                Master.Worksheets(1).Range("V" & lastrow + 1).Value = .Range("O69").Value
                Master.Worksheets(1).Range("W" & lastrow + 1).Value = .Range("P69").Value
                Master.Worksheets(1).Range("X" & lastrow + 1).Value = .Range("D92").Value
            End With
           
        sourceBook.Close
      
    'Calling DIR w/o argument finds the next .xlsx file within the current directory.
    CurrentFileName = Dir()
    Loop While CurrentFileName <> ""
    
    MsgBox "Consolidation complete"
    
    Application.ScreenUpdating = True
    Application.DisplayAlerts = True
    
    End Sub
    How/Where to install the macro:

    1. Open up your workbook
    2. Get into VB Editor (Press Alt+F11)
    3. Insert a new module (Insert > Module)
    4. Copy and Paste in your code (given above)
    5. Get out of VBA (Press Alt+Q)
    6. Save as a macro-enabled workbook

    The macro is installed and ready to use. Press Alt-F8 and select it from the macro list.

    Let me know if you want the macro to insert the headers for you. You can put them in the code - i can help you put them in the correct place.

  20. #20
    Registered User
    Join Date
    11-08-2012
    Location
    Wisconsin
    MS-Off Ver
    Excel 2010
    Posts
    41

    Re: Importing data from multiple files to new file

    Thank you very much for helping me!! I will let you know on Monday.

+ Reply to Thread

Thread Information

Users Browsing this Thread

There are currently 1 users browsing this thread. (0 members and 1 guests)

Bookmarks

Posting Permissions

  • You may not post new threads
  • You may not post replies
  • You may not post attachments
  • You may not edit your posts

Search Engine Friendly URLs by vBSEO 3.6.0 RC 1