Extracting specific cell values from multiple worksheets

jdhfch

Board Regular
Joined
Jan 25, 2018
Messages
75
Office Version
  1. 365
Platform
  1. Windows
Hi,

Please can someone help?

I have a folder with around 1200 individual XLSX files in, all the same format, but with different file names.

I am wanting to extract some info in only key cells in each file into a master file:

  1. Cell D1 - Name
  2. Cell D2 - Cust Number
  3. Cell D5
  4. Cell E65
  5. Cell F65
  6. Cell G65
  7. Cell H65
  8. Cell I65

An example layout would be:

NameCust NumberCell D5Cell E65Cell F65Cell G65Cell H65Cell I65
Example1234ColaPlain CrispsPlain NutsStill WaterBiscuitsBee
Is there any easy way to do this that can be updated frequently?

I am using Excel 365

Many thanks
 

Excel Facts

Create a Pivot Table on a Map
If your data has zip codes, postal codes, or city names, select the data and use Insert, 3D Map. (Found to right of chart icons).
Untested here but see what you come up with. This macro assumes your Master Workbook and all of the other workbooks to be opened all
reside in the same directory.

VBA Code:
Sub consolidatePres2()
Dim fPath As String, fName As String, wb As Workbook, sh As Worksheet
Set sh = ThisWorkbook.Sheets(1)
fPath = ThisWorkbook.Path

Application.ScreenUpdating = False

If Right(fPath, 1) <> "\" Then fPath = fPath & "\"
fName = Dir(fPath & "*.xl*")
    Do While fName <> ""
        If fName <> ThisWorkbook.Name Then
            Set wb = Workbooks.Open(fPath & fName)
                With wb.Sheets(1)
                    sh.Cells(Rows.Count, 1).End(xlUp)(2) = wb.Name
                    .Range("D1", "D2", "D5", "E65:I65").Copy sh.Cells(Rows.Count, 1).End(xlUp).Offset(, 1)
                End With
                wb.Close False
        End If
        fName = Dir
    Loop
Application.ScreenUpdating = True

Beep
MsgBox "All workbooks in folder have been processed."

End Sub
 
Upvote 0
VBA Code:
Sub ExtractData()
    Dim wb As Workbook
    Dim ws As Worksheet
    Dim MasterWS As Worksheet
    Dim FolderPath As String
    Dim Filename As String
    Dim RowCount As Long

    Set MasterWS = ThisWorkbook.Sheets("Sheet1")

    FolderPath = "C:\Your\Folder\Path\" 
    Filename = Dir(FolderPath & "*.xlsx")
    RowCount = 2 

    Do While Filename <> ""
        Set wb = Workbooks.Open(FolderPath & Filename, ReadOnly:=True)
        Set ws = wb.Sheets(1) 

        MasterWS.Cells(RowCount, 1).Value = ws.Range("D1").Value 
        MasterWS.Cells(RowCount, 2).Value = ws.Range("D2").Value 
        MasterWS.Cells(RowCount, 3).Value = ws.Range("D5").Value
        MasterWS.Cells(RowCount, 4).Value = ws.Range("E65").Value
        MasterWS.Cells(RowCount, 5).Value = ws.Range("F65").Value
        MasterWS.Cells(RowCount, 6).Value = ws.Range("G65").Value
        MasterWS.Cells(RowCount, 7).Value = ws.Range("H65").Value
        MasterWS.Cells(RowCount, 8).Value = ws.Range("I65").Value

        wb.Close SaveChanges:=False
        RowCount = RowCount + 1
        Filename = Dir()
    Loop

    MsgBox "Data extraction complete."
End Sub
 
Upvote 0
VBA Code:
Sub ExtractData()
    Dim wb As Workbook
    Dim ws As Worksheet
    Dim MasterWS As Worksheet
    Dim FolderPath As String
    Dim Filename As String
    Dim RowCount As Long

    Set MasterWS = ThisWorkbook.Sheets("Sheet1")

    FolderPath = "C:\Your\Folder\Path\"
    Filename = Dir(FolderPath & "*.xlsx")
    RowCount = 2

    Do While Filename <> ""
        Set wb = Workbooks.Open(FolderPath & Filename, ReadOnly:=True)
        Set ws = wb.Sheets(1)

        MasterWS.Cells(RowCount, 1).Value = ws.Range("D1").Value
        MasterWS.Cells(RowCount, 2).Value = ws.Range("D2").Value
        MasterWS.Cells(RowCount, 3).Value = ws.Range("D5").Value
        MasterWS.Cells(RowCount, 4).Value = ws.Range("E65").Value
        MasterWS.Cells(RowCount, 5).Value = ws.Range("F65").Value
        MasterWS.Cells(RowCount, 6).Value = ws.Range("G65").Value
        MasterWS.Cells(RowCount, 7).Value = ws.Range("H65").Value
        MasterWS.Cells(RowCount, 8).Value = ws.Range("I65").Value

        wb.Close SaveChanges:=False
        RowCount = RowCount + 1
        Filename = Dir()
    Loop

    MsgBox "Data extraction complete."
End Sub

Thank you. Please can I ask how to modify this code to ask for the folder, rather than specifying a specific folder. This is what I have so far:

Sub ExtractData()
Dim wb As Workbook
Dim ws As Worksheet
Dim MasterWS As Worksheet
Dim FolderPath As String
Dim Filename As String
Dim RowCount As Long

Set MasterWS = ThisWorkbook.Sheets("Sheet1")

FolderPath = "C:\Users\Test\OneDrive - Test\Documents\Test\Test\Test\"
Filename = Dir(FolderPath & "*.xlsx")
RowCount = 2

Do While Filename <> ""
Set wb = Workbooks.Open(FolderPath & Filename, ReadOnly:=True)
Set ws = wb.Sheets(1)

MasterWS.Cells(RowCount, 1).Value = ws.Range("D1").Value
MasterWS.Cells(RowCount, 2).Value = ws.Range("D2").Value
MasterWS.Cells(RowCount, 3).Value = ws.Range("D5").Value
MasterWS.Cells(RowCount, 4).Value = ws.Range("E65").Value
MasterWS.Cells(RowCount, 5).Value = ws.Range("F65").Value
MasterWS.Cells(RowCount, 6).Value = ws.Range("G65").Value
MasterWS.Cells(RowCount, 7).Value = ws.Range("H65").Value
MasterWS.Cells(RowCount, 8).Value = ws.Range("I65").Value

wb.Close SaveChanges:=False
RowCount = RowCount + 1
Filename = Dir()
Loop

MsgBox "Data extraction complete."
End Sub
 
Upvote 0
I appreciate the support - as always :)
 
Last edited:
Upvote 0
I have a folder with around 1200 individual XLSX files in, all the same format, but with different file names.
Doesn't open each workbook.
Code:
Sub test()
    Dim myDir$, fn$, s$(1), wsName$, myList, i&
    With Application.FileDialog(msoFileDialogFolderPicker)
        If .Show Then myDir = .SelectedItems(1) & "\"
    End With
    If myDir = "False" Then Exit Sub
    ThisWorkbook.Sheets(1).[a1].CurrentRegion.ClearContents
    myList = Split("D1,D2,D5,E65,F65,G65,H65,I65", ",")
    fn = Dir(myDir & "*.xls*")
    Do While fn <> ""
        If myDir & fn <> ThisWorkbook.FullName Then
            wsName = GetSheetName(myDir & fn)
            s(0) = "'" & myDir & "[" & fn & "]" & wsName & "'!"
            With ThisWorkbook.Sheets(1).Range("a" & Rows.Count).End(xlUp)(2)
                .Cells(1) = fn
                For i = 0 To UBound(myList)
                    s(1) = s(0) & Range(myList(i)).Address(, , 2)
                    .Cells(1, i + 2) = ExecuteExcel4Macro("if(" & s(1) & "<>""""," & s(1) & ","""")")
                Next
            End With
        End If
        fn = Dir
    Loop
End Sub

Function GetSheetName(fn As String) As String
    With CreateObject("DAO.DBEngine.120").workspaces(0).OpenDatabase(fn, True, True, "excel 12.0;HDR=No;")
        GetSheetName = Replace(.tabledefs(0).Name, "'", "")
        GetSheetName = Left$(GetSheetName, Len(GetSheetName) - 1)
        .Close
    End With
End Function
 
Upvote 0
Doesn't open each workbook.
Code:
Sub test()
    Dim myDir$, fn$, s$(1), wsName$, myList, i&
    With Application.FileDialog(msoFileDialogFolderPicker)
        If .Show Then myDir = .SelectedItems(1) & "\"
    End With
    If myDir = "False" Then Exit Sub
    ThisWorkbook.Sheets(1).[a1].CurrentRegion.ClearContents
    myList = Split("D1,D2,D5,E65,F65,G65,H65,I65", ",")
    fn = Dir(myDir & "*.xls*")
    Do While fn <> ""
        If myDir & fn <> ThisWorkbook.FullName Then
            wsName = GetSheetName(myDir & fn)
            s(0) = "'" & myDir & "[" & fn & "]" & wsName & "'!"
            With ThisWorkbook.Sheets(1).Range("a" & Rows.Count).End(xlUp)(2)
                .Cells(1) = fn
                For i = 0 To UBound(myList)
                    s(1) = s(0) & Range(myList(i)).Address(, , 2)
                    .Cells(1, i + 2) = ExecuteExcel4Macro("if(" & s(1) & "<>""""," & s(1) & ","""")")
                Next
            End With
        End If
        fn = Dir
    Loop
End Sub

Function GetSheetName(fn As String) As String
    With CreateObject("DAO.DBEngine.120").workspaces(0).OpenDatabase(fn, True, True, "excel 12.0;HDR=No;")
        GetSheetName = Replace(.tabledefs(0).Name, "'", "")
        GetSheetName = Left$(GetSheetName, Len(GetSheetName) - 1)
        .Close
    End With
End Function
Thank you - is there any way of including headers on row 1, and not clearing content from columns J onwards please?
 
Upvote 0
Where is it?
Do you mean the headers? They would be
a1 - Filename
b1 - Client no
c1 - Client name
d1 - Manager
e1 - list 1
f1 - list 2
g1 - list 3
h1 - list 4
i1 - list 5

Then leave from J uncleared?
 
Upvote 0
Change
Code:
    ThisWorkbook.Sheets(1).[a1].CurrentRegion.ClearContents
to
Rich (BB code):
    ThisWorkbook.Sheets(1).[a1].CurrentRegion.Resize(, 9).ClearContents
    ThisWorkbook.Sheets(1).[a1:i1] = Array("Filename", "Client no", "Client name", _
        "Manager", "list 1", "list 2", "list 3", "list 4", "list 5")
 
Upvote 0

Forum statistics

Threads
1,223,099
Messages
6,170,114
Members
452,302
Latest member
TaMere

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