Crazy Data Aggregation Question

aallaman

New Member
Joined
Dec 4, 2009
Messages
44
Hi All,

You have helped me out tons in the past with some of my Excel mindbenders and here is another one if anyone can help!

I have 100+ worksheets spread across about nine workbooks with data that needs aggregated together. Each workbook has identical fields between its own worksheets, but the data between workbooks have slightly different field names and some have more field names than others.

I need to take each workbook and aggregate every worksheet in that book into one dataset. Unfortunately the data is not a flat dataset in every worksheet, however they are formated the same. For example, some worksheets have one or two blank rows before the column heading row for that sheet's dataset.

Can anyone think of a macro that would look at each sheet of a book, take the dataset minus the header row, and combine the data from every sheet in that book into one block of data in a new sheet named CompleteData or something like that? I also need to pull the sheet name into the new dataset.

Here is an example of the data that I need to combine:
https://docs.google.com/spreadsheet...EJDdjVxak1hRWxMQWpMZ1JmNFE5Z2c&hl=en_US#gid=0

Any ideas?

THANKS!
Allen
 

Excel Facts

Do you hate GETPIVOTDATA?
Prevent GETPIVOTDATA. Select inside a PivotTable. In the Analyze tab of the ribbon, open the dropown next to Options and turn it off
Code:
Sub Consolidate_Sheets()

    Dim ws As Worksheet
    Dim wsFinal As Worksheet
    Dim Lastcol As Long
    Dim Nextrow As Long
    Dim Firstrow As Long
    Dim Lastrow As Long
    
    On Error Resume Next
        Set wsFinal = Sheets("Final Data")
    On Error GoTo 0
    If Not wsFinal Is Nothing Then
        MsgBox "Sheet ""Final Data"" already exists. ", , "Final Data Exists"
        Exit Sub
    End If
    
    Application.ScreenUpdating = False
    Set wsFinal = ActiveWorkbook.Sheets.Add(After:=Sheets(Sheets.Count))
    wsFinal.Name = "Final Data"
    If Sheets(1).Range("A1").Value <> "" Then
        Sheets(1).Range("A1").EntireRow.Copy wsFinal.Range("1:1")
    Else
        Sheets(1).Range("A1").End(xlDown).EntireRow.Copy wsFinal.Range("1:1")
    End If
    Lastcol = wsFinal.Cells(1, wsFinal.Columns.Count).End(xlToLeft).Column + 1
    wsFinal.Cells(1, Lastcol).Value = "Worksheet"
    
    For Each ws In ActiveWorkbook.Sheets
        If ws.Name <> wsFinal.Name Then
        
            Nextrow = wsFinal.Range("A" & Rows.Count).End(xlUp).Row + 1
            If ws.Range("A1").Value <> "" Then
                Firstrow = 2
            Else
                Firstrow = ws.Range("A1").End(xlDown).Row + 1
            End If
            Lastrow = ws.Range("A" & ws.Rows.Count).End(xlUp).Row
            
            With ws.Range(ws.Cells(Firstrow, 1), ws.Cells(Lastrow, Lastcol - 1))
                wsFinal.Cells(Nextrow, 1).Resize(.Rows.Count, .Columns.Count).Value = .Value
                wsFinal.Cells(Nextrow, Lastcol).Resize(.Rows.Count).Value = ws.Name
            End With
            
        End If
    Next ws
    wsFinal.Cells.Columns.AutoFit
    Application.ScreenUpdating = True
End Sub
 
Last edited:
Upvote 0

Forum statistics

Threads
1,214,918
Messages
6,122,246
Members
449,075
Latest member
staticfluids

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