Need some macro

Ron99

Active Member
Joined
Feb 10, 2010
Messages
347
Office Version
  1. 2016
Platform
  1. Windows
Hi,

I have a worksheet, which has 50 tabs and each of the 50 tab has data in it. I would like to consolidate all the data in the tabs to one sheet.

for example - sheet1 has data till the row 200, sheet2 has it till 300, data varies from tab to tab.

I want the code which copies data from sheet1 paste it in master tab, and copy the data from sheet2 paste it in master tab where the data of the first sheet has ended...it goes on for all the tabs.


Regards,
Ron..
 

Excel Facts

Copy PDF to Excel
Select data in PDF. Paste to Microsoft Word. Copy from Word and paste to Excel.
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 
         '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


give that one a try, seems to do the trick for me.
 
Upvote 0
Too good!!!....excelllent coding...works fine

Thank you
 
Upvote 0

Forum statistics

Threads
1,224,505
Messages
6,179,147
Members
452,891
Latest member
JUSTOUTOFMYREACH

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