• Hi All

    Please note that at the Chandoo.org Forums there is Zero Tolerance to Spam

    Post Spam and you Will Be Deleted as a User

    Hui...

  • When starting a new post, to receive a quicker and more targeted answer, Please include a sample file in the initial post.

Combine data from Multiple worksheet into Single worksheet

Dear Gurus,

Kindly help me with macro to combine data in multiple worksheet into a single worksheet.
I have attached sample worksheets.

I need to combile data from book-1 & book-2 in same sheet in consecutive running rows.
I have attached a sample format of output file for the same.Just colour shading is done in output file to show the difference of login data.

Thanks in advance.
 

Attachments

  • Book-1.xlsx
    29.1 KB · Views: 4
  • Book-2.xlsx
    28.5 KB · Views: 4
  • Output.xlsx
    46.7 KB · Views: 5
@Vignesh Veerasamy

See below code, taken from same link and modified a bit. I had left the remarks.
Save all excel files which need to be summarized in a folder. Open a new file. Paste the code and run it.

Please keep a backup of your files first and run this first on a sample file. Change the folder path as mentioned in the code.

Code:
Sub MergeAllWorkbooks()
    Dim SummarySheet As Worksheet
    Dim FolderPath As String
    Dim NRow As Long
    Dim FileName As String
    Dim WorkBk As Workbook
    Dim SourceRange As Range
    Dim DestRange As Range
    Dim lr As Long
   
    ' Create a new workbook and set a variable to the first sheet.
    Set SummarySheet = Sheets("Sheet1")
   
    ' Modify this folder path to point to the files you want to use.
    FolderPath = "C:\Users\A075970\Desktop\Sample\"
   
    ' NRow keeps track of where to insert new rows in the destination workbook.
    NRow = 3
   
    ' Call Dir the first time, pointing it to all Excel files in the folder path.
    FileName = Dir(FolderPath & "*.xl*")
   
    ' Loop until Dir returns an empty string.
    Do While FileName <> ""
        ' Open a workbook in the folder
        Set WorkBk = Workbooks.Open(FolderPath & FileName)
       
        ' Set the cell in column A to be the file name.
        'SummarySheet.Range("A" & NRow).Value = FileName
       
        ' Set the source range to be A9 through C9.
        ' Modify this range for your workbooks.
        ' It can span multiple rows.
        lr = Range("B" & Rows.Count).End(xlUp).Row
        Set SourceRange = WorkBk.Worksheets(1).Range("B3:F" & lr)
       
        ' Set the destination range to start at column B and
        ' be the same size as the source range.
        Set DestRange = SummarySheet.Range("B" & NRow)
        Set DestRange = DestRange.Resize(SourceRange.Rows.Count, _
          SourceRange.Columns.Count)
         
        ' Copy over the values from the source to the destination.
        DestRange.Value = SourceRange.Value
       
        ' Increase NRow so that we know where to copy data next.
        NRow = NRow + DestRange.Rows.Count
       
        ' Close the source workbook without saving changes.
        WorkBk.Close savechanges:=False
       
        ' Use Dir to get the next file name.
        FileName = Dir()
    Loop
   
    ' Call AutoFit on the destination sheet so that all
    ' data is readable.
    SummarySheet.Columns.AutoFit
End Sub

Regards,
 
Back
Top