Combine Few Sheets to one summary

joycesolomon

New Member
Joined
Aug 2, 2011
Messages
48
Hi

I found the below code and it works great:
Code:
[COLOR=blue]Sub[/COLOR] CopyFromWorksheets() 
    [COLOR=blue]Dim[/COLOR] wrk [COLOR=blue]As[/COLOR] Workbook [COLOR=darkgreen]'Workbook object - Always good to work with object variables[/COLOR]
    [COLOR=blue]Dim[/COLOR] sht [COLOR=blue]As[/COLOR] Worksheet [COLOR=darkgreen]'Object for handling worksheets in loop[/COLOR]
    [COLOR=blue]Dim[/COLOR] trg [COLOR=blue]As[/COLOR] Worksheet [COLOR=darkgreen]'Master Worksheet[/COLOR]
    [COLOR=blue]Dim[/COLOR] rng [COLOR=blue]As[/COLOR] Range [COLOR=darkgreen]'Range object[/COLOR]
    [COLOR=blue]Dim[/COLOR] colCount [COLOR=blue]As[/COLOR] [COLOR=blue]Integer[/COLOR] [COLOR=darkgreen]'Column count in tables in the worksheets[/COLOR]
     
    [COLOR=blue]Set[/COLOR] wrk = ActiveWorkbook [COLOR=darkgreen]'Working in active workbook[/COLOR]
     
    [COLOR=blue]For 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" 
            Exit [COLOR=blue]Sub[/COLOR] 
        [COLOR=blue]End[/COLOR] [COLOR=blue]If[/COLOR] 
    [COLOR=blue]Next[/COLOR] sht 
     
     [COLOR=darkgreen]'We don't want screen updating[/COLOR]
    Application.ScreenUpdating = [COLOR=blue]False[/COLOR] 
     
     [COLOR=darkgreen]'Add new worksheet as the last worksheet[/COLOR]
    [COLOR=blue]Set[/COLOR] trg = wrk.Worksheets.Add(After:=wrk.Worksheets(wrk.Worksheets.Count)) 
     [COLOR=darkgreen]'Rename the new worksheet[/COLOR]
    trg.Name = "Master" 
     [COLOR=darkgreen]'Get column headers from the first worksheet[/COLOR]
     [COLOR=darkgreen]'Column count first[/COLOR]
    [COLOR=blue]Set[/COLOR] sht = wrk.Worksheets(1) 
    colCount = sht.Cells(1, 255).End(xlToLeft).Column 
     [COLOR=darkgreen]'Now retrieve headers, no copy&paste needed[/COLOR]
    [COLOR=blue]With[/COLOR] trg.Cells(1, 1).Resize(1, colCount) 
        .Value = sht.Cells(1, 1).Resize(1, colCount).Value 
         [COLOR=darkgreen]'Set font as bold[/COLOR]
        .Font.Bold = [COLOR=blue]True[/COLOR] 
    [COLOR=blue]End With[/COLOR] 
     
     [COLOR=darkgreen]'We can start loop[/COLOR]
    [COLOR=blue]For Each[/COLOR] sht [COLOR=blue]In[/COLOR] wrk.Worksheets 
         [COLOR=darkgreen]'If worksheet in loop is the last one, stop execution (it is Master worksheet)[/COLOR]
        [COLOR=blue]If[/COLOR] sht.Index = wrk.Worksheets.Count [COLOR=blue]Then[/COLOR] 
            Exit [COLOR=blue]For[/COLOR] 
        [COLOR=blue]End[/COLOR] [COLOR=blue]If[/COLOR] 
         [COLOR=darkgreen]'Data range in worksheet - starts from second row as first rows are the header rows in all worksheets[/COLOR]
        [COLOR=blue]Set[/COLOR] rng = sht.Range(sht.Cells(2, 1), sht.Cells(65536, 1).End(xlUp).Resize(, colCount)) 
         [COLOR=darkgreen]'Put data into the Master worksheet[/COLOR]
        trg.Cells(65536, 1).End(xlUp).Offset(1).Resize(rng.Rows.Count, rng.Columns.Count).Value = rng.Value 
    [COLOR=blue]Next[/COLOR] sht 
     [COLOR=darkgreen]'Fit the columns in Master worksheet[/COLOR]
    trg.Columns.AutoFit 
     
     [COLOR=darkgreen]'Screen updating should be activated[/COLOR]
    Application.ScreenUpdating = [COLOR=blue]True[/COLOR] 
[COLOR=blue]End Sub[/COLOR]

But this code copies from all the available sheets. I only want it to copy from sheet named 1 to 100. Can someone show me how to improve this code for that purpose?

Thanks
 

Excel Facts

How to change case of text in Excel?
Use =UPPER() for upper case, =LOWER() for lower case, and =PROPER() for proper case. PROPER won't capitalize second c in Mccartney
Are the sheets actually named:
1,2,3,...
or
Sheet1, Sheet2, Sheet3,...?
 
Upvote 0
Following the logic you have already used in your code, maybe you could do something like:

Code:
    For Each sht In wrk.Worksheets
        If sht.Name <= 100 then
            ...
        Else
            Exit For
        End If
        ...
     Next sht
 
Upvote 0
Here is the code that i placed in after your reply:

Code:
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
            Exit For
        End If
      
     If sht.Name <= 100 Then
         '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
        Else
          Exit For
     End If
     Next sht
     'Fit the columns in Master worksheet
    trg.Columns.AutoFit
     
     'Screen updating should be activated
    Application.ScreenUpdating = True
    
    
End Sub

It gives out error "Type mismatched " at If sht.Name <= 100 Then

did i place the IF statement at the right place?
 
Upvote 0
That probably tells me that you have some non-numeric named sheets in your workbook wreaking havoc with that IF statement. You may need another level to check to see if the sheet name is numeric first, i.e.
Code:
    For Each sht In wrk.Worksheets
        If IsNumeric(sht.Name) Then
            If sht.Name <= 100 Then
                ...
 
Upvote 0
This works great, thank you.

Just another issue.

Some of the sheets are having empty records except for the column header. So the code actually picks up the column header instead of just skipping it, how do i make it skip if there is no record?
 
Upvote 0
Locate the last row, and see if it is greater than one.

For example, let's say we are using column A to determine how many rows there are:
Code:
MyLastRow=Cells(Rows.Count,"A").End(xlUp).Row
If MyLastRow>1 Then
'   ... copy code here
End If
 
Upvote 0
Can you please coach me to where would i put it?

I had set my code to below, but not getting any output:

Code:
 '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
            Exit For
        End If
     If IsNumeric(sht.Name) Then
       If (sht.Name <= 340) Or (sht.Name >= 1) Then
         '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
             MyLastRow = Cells(Rows.Count, "A").End(xlUp).Row
             If MyLastRow > 1 Then
                trg.Cells(65536, 1).End(xlUp).Offset(1).Resize(rng.Rows.Count, rng.Columns.Count).Value = rng.Value
             End If
       Else
          Exit For
     End If
     End If
     Next sht
     'Fit the columns in Master worksheet
    trg.Columns.AutoFit
     
     'Screen updating should be activated
    Application.ScreenUpdating = True
 
Upvote 0

Forum statistics

Threads
1,215,358
Messages
6,124,487
Members
449,165
Latest member
ChipDude83

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