Consolidate Worksheets into a Single Worksheet

Ken_W

New Member
Joined
May 7, 2015
Messages
17
I have a Workbook with several hundred worksheets, which I need to merge/consolidate into a single worksheet. I found some code that I was able to slightly modify for my purposes and works perfect with the exception of some formatting of the data problems. I have a test version of my workbook here:
https://app.box.com/s/8wju200wyh8mxmsda1q9ajsh9gi4txjy

Most of the data is consolidated correctly, however, some of the data formats are changed in column D and Column H. For example, there's a worksheet names 0447 and column D's value is 0447, but when I run the code it drops the leading zero.

Regarding column H, this data is often interpreted as a date, but it's not and it needs to maintain its original value e.g. 1-1-1 vice 1/1/2001.

So basically I need columns D and H to be formatted as text to maintain the values. I don't want to format all columns to text, as some columns do have numerical values, which I need to maintain.

Just to be clear, I'm not a VBA coder and as I said, most of this was pulled from another source I found.

Thanks in advance!

Ken

The code is as follows:
Sub CopyFromWorksheets()
Dim wrk As Workbook 'Workbook object - Always good to work with object variables
Dim sht As Worksheet 'Object for handling worksheets in loop
Dim trg As Worksheet 'Master Worksheet
Dim rng As Range 'Range object
Dim colCount As Integer 'Column count in tables in the worksheets

Set wrk = ActiveWorkbook 'Working in active workbook

For Each sht In wrk.Worksheets
If sht.Name = "Master" Then
MsgBox "There is a worksheet called as 'Master'." & vbCrLf & _
"Please remove or rename this worksheet since 'Master' would be" & _
"the name of the result worksheet of this process.", vbOKOnly + vbExclamation, "Error"
Exit Sub
End If
Next sht

'We don't want screen updating
Application.ScreenUpdating = False

'Add new worksheet as the last worksheet
Set trg = wrk.Worksheets.Add(After:=wrk.Worksheets(wrk.Worksheets.Count))
'Rename the new worksheet
trg.Name = "Master"
'Get column headers from the first worksheet
'Column count first
Set sht = wrk.Worksheets(1)
colCount = sht.Cells(1, 255).End(xlToLeft).Column
'Now retrieve headers, no copy&paste needed
With trg.Cells(1, 1).Resize(1, colCount)
.Value = sht.Cells(1, 1).Resize(1, colCount).Value
'Set font as bold
.Font.Bold = True
End With

'We can start loop
For Each sht In wrk.Worksheets
'If worksheet in loop is the last one, stop execution (it is Master worksheet)
If sht.Index = wrk.Worksheets.Count Then
Range("A1").Select
With ActiveWindow
.SplitColumn = 0
.SplitRow = 1
End With
ActiveWindow.FreezePanes = True
Selection.AutoFilter
Exit For
End If
'Data range in worksheet - starts from second row as first rows are the header rows in all worksheets
Set rng = sht.Range(sht.Cells(2, 1), sht.Cells(65536, 1).End(xlUp).Resize(, colCount))
'Put data into the Master worksheet
trg.Cells(65536, 1).End(xlUp).Offset(1).Resize(rng.Rows.Count, rng.Columns.Count).Value = rng.Value
Next sht
'Fit the columns in Master worksheet
trg.Columns.AutoFit

'Screen updating should be activated
Application.ScreenUpdating = True
End Sub
 

Excel Facts

Get help while writing formula
Click the italics "fx" icon to the left of the formula bar to open the Functions Arguments dialog. Help is displayed for each argument.
..

Thank you very much, that did the trick.........
....
Ken

Hi Ken,

. Yous welcome, thanks for the feedback and Link
Alan

P.s. Minor point: That code is old and based on early XL versions with smaller spreadsheets. In the ( admittedly maybe unlikely ) event that you had more than 256 columns or more than 65536 rows then the code would not work in your file which I assume version XL 2007 or above.
. Normally nowadays the 255 and 65536 references in that code would be replaced by applying the .Count Property to the Rows and Columns Property respectively to make the code compatible with all the older and newer versions....

...This would be the Modified code..( with a few more explaining comments for mine ( if no-one else! ) later reference when viewing this Thread ( You picked a good title so others with a similar requirement may come here in the future )

Code:
[color=blue]Sub[/color] CopyFromWorksheets()
[color=lightgreen]'http://www.vbaexpress.com/kb/getarticle.php?kb_id=151[/color]
[color=lightgreen]'http://www.mrexcel.com/forum/excel-questions/866161-consolidate-worksheets-into-single-worksheet.html[/color]
    [color=blue]Dim[/color] wrk [color=blue]As[/color] Workbook [color=lightgreen]'Workbook object - Always good to work with object variables - Give Abbreviation Methods, Properties of Object through .dot[/color]
    [color=blue]Dim[/color] sht [color=blue]As[/color] Worksheet [color=lightgreen]'Object for handling worksheets in loop[/color]
    [color=blue]Dim[/color] trg [color=blue]As[/color] Worksheet [color=lightgreen]'Object Master Worksheet[/color]
    [color=blue]Dim[/color] rng [color=blue]As[/color] Range [color=lightgreen]'Range object[/color]
    [color=blue]Dim[/color] colCount [color=blue]As[/color] [color=blue]Long[/color] 'Column count in tables in the worksheets'Long is a Big whole Number limit (-2,147,483,648 to 2,147,483,647) If you need some sort of validation the value should only be within the range of a Byte/Integer otherwise there's no point using anything but Long.--upon/after 32-bit, Integers (Short) need converted internally anyways, so a Long is actually faster.
    
    [color=blue]Set[/color] wrk = ActiveWorkbook [color=lightgreen]'Working in active workbook' Alternative Set wrk = ThisWorkbook'Working in Workbook this code is in[/color]
    [color=blue]For[/color] [color=blue]Each[/color] sht [color=blue]In[/color] wrk.Worksheets
        [color=blue]If[/color] sht.Name = "Master" [color=blue]Then[/color]
            MsgBox "There is a worksheet called as 'Master'." & vbCrLf & _
            "Please remove or rename this worksheet since 'Master' would be" & _
            "the name of the result worksheet of this process.", vbOKOnly + vbExclamation, "Error"
            [color=blue]Exit[/color] [color=blue]Sub[/color]
        [color=blue]End[/color] [color=blue]If[/color]
    [color=blue]Next[/color] sht
    
     [color=lightgreen]'We don't want screen updating as this slows things down[/color]
     Application.ScreenUpdating = [color=blue]False[/color]
    
     [color=lightgreen]'Add new worksheet after the last worksheet[/color]
    [color=blue]Set[/color] trg = wrk.Worksheets.Add(After:=wrk.Worksheets(wrk.Worksheets.Count))
     [color=lightgreen]'Rename the new worksheet[/color]
    trg.Name = "Master"
     [color=lightgreen]'Get column headers from the first worksheet[/color]
     [color=lightgreen]'Column count first[/color]
    [color=blue]Set[/color] sht = wrk.Worksheets.Item(1) [color=lightgreen]'First sheet ever put in workbook ( Original "Sheet1" )[/color]
        [color=lightgreen]'    colCount = sht.Cells(1, 255).End(xlToLeft).Column '256 is max columns for pre XL 2007, 16,384 for XL2007+[/color]
    colCount = sht.Cells(1, Columns.Count).End(xlToLeft).Column [color=lightgreen]'The last cell in row 1 has the .End(argument to left) applied which returns a new range ( cell ) that being the last one with an entry in it. The column property is then applied to that cell to return the column number[/color]
     [color=lightgreen]'Now retrieve headers, (no copy&paste needed as only values are copied, quicker to by-pass the clipboard and just assign values from first sheet item[/color]
    [color=blue]With[/color] trg.Cells(1, 1).Resize(1, colCount) [color=lightgreen]'The first cell is resized to that including all the headers and....[/color]
        .Value = sht.Cells(1, 1).Resize(1, colCount).Value [color=lightgreen]'... its value is taken as that for the corresponding range in sheet item 1[/color]
         [color=lightgreen]'Set font as bold[/color]
        .Font.Bold = [color=blue]True[/color]
    [color=blue]End[/color] [color=blue]With[/color]
        [color=lightgreen]'Change column D and H to text format in trg sheet.[/color]
        trg.Columns("D").NumberFormat = "@"
        trg.Columns(8).NumberFormat = "@" [color=lightgreen]'Column Number counting from left 8 = H[/color]
    
     [color=lightgreen]'We can start loop[/color]
    [color=blue]For[/color] [color=blue]Each[/color] sht [color=blue]In[/color] wrk.Worksheets
         [color=lightgreen]'If worksheet in loop is the last one, ( the master )do some autofilter stuff Ken wants, then stop execution.[/color]
        [color=blue]If[/color] sht.Index = wrk.Worksheets.Count [color=blue]Then[/color]
        Range("A1").Select
        [color=blue]With[/color] ActiveWindow
            .SplitColumn = 0
            .SplitRow = 1
        [color=blue]End[/color] [color=blue]With[/color]
        ActiveWindow.FreezePanes = [color=blue]True[/color]
        Selection.AutoFilter
    [color=blue]Exit[/color] [color=blue]For[/color]
        [color=blue]End[/color] [color=blue]If[/color]
         [color=lightgreen]'Data range in worksheet - starts from second row as first rows are the header rows in all worksheets[/color]
                [color=lightgreen]'Set rng = sht.Range(sht.Cells(2, 1), sht.Cells(65536, 1).End(xlUp).Resize(, colCount)) 'Max Rows is 65,536 for pre XL 2007, 1,048,576 for XL2007+[/color]
         [color=blue]Set[/color] rng = sht.Range(sht.Cells(2, 1), sht.Cells(Rows.Count, 1).End(xlUp).Resize(, colCount)) [color=lightgreen]'Range from cell  (second row , column 1)  , to Range that is cell last row resized to column maximum which returns last cell bottom right (As the first argument is omitted, the row number in the range ( cell ) remains the same )[/color]
         [color=lightgreen]'Put data into the Master worksheet[/color]
                [color=lightgreen]'trg.Cells(65536, 1).End(xlUp).Offset(1).Resize(rng.Rows.Count, rng.Columns.Count).Value = rng.Value[/color]
        trg.Cells(Rows.Count, 1).End(xlUp).Offset(1).Resize(rng.Rows.Count, rng.Columns.Count).Value = rng.Value [color=lightgreen]'Following through this long line: Our trg range is initially the next free cell in the Master sheet column 1 (So offset by 1 from the last cell in column 1) .  But it is then resized to the Row and column size of the rng to be copied. We then have equal size ranges and can equate their values in the VBA allowed "one Liner" assignment[/color]
    [color=blue]Next[/color] sht
     [color=lightgreen]'Fit the columns in Master worksheet[/color]
    trg.Columns.AutoFit
    
     [color=lightgreen]'Screen updating should be activated[/color]
    Application.ScreenUpdating = [color=blue]True[/color]
[color=blue]End[/color] [color=blue]Sub[/color]
 
Upvote 0

Forum statistics

Threads
1,215,873
Messages
6,127,454
Members
449,383
Latest member
DonnaRisso

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