VBA to read files in directory and total two columns

ROBINSON_US

New Member
Joined
Feb 27, 2006
Messages
25
Good Morning, I have a directory with 20-30 files (it could change every month) with all the same layout, but different amount of rows. I need to total up two columns, and came up with the following, but it is erroring out on the lRow line. I should mention that I've used this code when totaling up all the worksheets in 1 file, but it doesn't want to seem to work with separate files. Any suggestions?
Thanks
Code:
Sub TotalUpReports()
    
    FolderName = "C:\Reports\Monthly Reports"
    If Right(FolderName, 1) <> Application.PathSeparator Then FolderName = FolderName & Application.PathSeparator
    Fname = Dir(FolderName & "*.xlxs")

    Do While Len(Fname)
        With Workbooks.Open(FolderName & Fname)
 Dim lRow As Long
 lRow = .Cells(.Rows.Count,"R").End(xlUp).Row
'title rows are 1 & 2
 Cells(lRow + 2, 12).Value = Application.Sum(Range(Cells(3, 12), Cells(lRow, 12)))
 Cells(lRow + 2, 18).Value = Application.Sum(Range(Cells(3, 18), Cells(lRow, 18)))
    
    ws.Range("A" & lRow + 2).Value = "TOTALS"
    ws.Range("A" & lRow + 2).Font.Bold = True
         
        End With
        Fname = Dir
    Loop
    
End Sub
 
Last edited by a moderator:

Excel Facts

How can you automate Excel?
Press Alt+F11 from Windows Excel to open the Visual Basic for Applications (VBA) editor.
Try this. Assumes the columns are in the 1st worksheet of each workbook.
Code:
Sub TotalUpReports()

    Dim folderName As String, fileName As String
    Dim lRow As Long
    Dim openedWb As Workbook
    
    Set destSheet = ActiveWorkbook.Worksheets(1)
    
    folderName = "C:\Reports\Monthly Reports"
    folderName = "C:\Temp\Excel\Workbooks"
    If Right(folderName, 1) <> Application.PathSeparator Then folderName = folderName & Application.PathSeparator
    
    fileName = Dir(folderName & "Totals*.xlsx")
    Do While Len(fileName)
        Set openedWb = Workbooks.Open(folderName & fileName)
        With openedWb.Worksheets(1)
            lRow = .Cells(.Rows.Count, "R").End(xlUp).Row
            'title rows are 1 & 2
            .Cells(lRow + 2, "L").Value = Application.Sum(Range(.Cells(3, "L"), .Cells(lRow, "L")))
            .Cells(lRow + 2, "R").Value = Application.Sum(Range(.Cells(3, "R"), .Cells(lRow, "R")))
            .Cells(lRow + 2, "A").Value = "TOTALS"
            .Cells(lRow + 2, "A").Font.Bold = True
        End With
        openedWb.Close True
        fileName = Dir
    Loop

End Sub
 
Upvote 0
Delete:
Code:
    folderName = "C:\Temp\Excel\Workbooks"
Change:
Code:
    fileName = Dir(folderName & "Totals*.xlsx")
To:
Code:
    fileName = Dir(folderName & "*.xlsx")
 
Last edited:
Upvote 0
THANK YOU! Can't express my appreciation enough. This culminates a 3 month project I've been working on. Truly appreciate your help.
 
Upvote 0

Forum statistics

Threads
1,223,234
Messages
6,170,891
Members
452,366
Latest member
TePunaBloke

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