• 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.

Data Consolidation Easy Question

I have the code below and all I want to do is have the filename copied in all rows that contain data from the copied workbook. So, if in one workbook the Accruals row count is 35 rows, then I want the filename in all 35 rows.

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
 
  ' Create a new workbook and set a variable to the first sheet.
  Set SummarySheet = Workbooks.Add(xlWBATWorksheet).Worksheets(1)
 
  ' Modify this folder path to point to the files you want to use.
  FolderPath = "C:Test Data\"
 
  ' NRow keeps track of where to insert new rows in the destination workbook.
  NRow = 1
 
  ' 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.
  Set SourceRange = WorkBk.Worksheets(1).Range("Accruals")
 
  ' 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
 
Line added in to copy file name in column to right of where you pasted data.
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

' Create a new workbook and set a variable to the first sheet.
Set SummarySheet = Workbooks.Add(xlWBATWorksheet).Worksheets(1)

' Modify this folder path to point to the files you want to use.
FolderPath = "C:Test Data\"

' NRow keeps track of where to insert new rows in the destination workbook.
NRow = 1

' 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.
    Set SourceRange = WorkBk.Worksheets(1).Range("Accruals")
   
    ' 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
   
    '====NEW ADDITION====
    DestRange.Offset(0, DestRange.Columns.Count).Resize(, 1).Value = WorkBk.Name
    '====END ADDITION====
   
    ' 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
 
Back
Top