PDA

View Full Version : Combine Specific Worksheets into One



jasonr704
03-26-2010, 10:46 AM
I need some help re-writing the "Combine All Worksheets into One" macro so that it only includes the following worksheets:
pre-1, pre-2, pre-3, pre-4, pre-5, pre-6, pre-7, pre-8, suff-9, suff-10, suff-11, suff-12, suff-13, suff-14, suff-15, suff-16

These are the worksheets that have identical column structure and can be combined together.
--------------------------------------------------------------
Here's the original code for Combine All Worksheets into One.

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


Thanks VERY much for the help!

SamT
03-26-2010, 12:38 PM
Try This

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("pre-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
'
'
'
Dim i As Long
Dim ShtNames
ShtNames = Array("pre-1", "pre-2", "pre-3", "pre-4", "pre-5", "pre-6", _
"pre-7", "pre-8", "suff-9", "suff-10", "suff-11", "suff-12", _
"suff-13", "suff-14", "suff-15", "suff-16")
'We can start loop
For i = LBound(ShtNames) To UBound(ShtNames)
Set sht = ShtNames(i)
'
'
'
'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 i
'Fit the columns in Master worksheet
trg.Columns.AutoFit
'Screen updating should be activated
Application.ScreenUpdating = True
End Sub

jasonr704
03-26-2010, 04:37 PM
I replaced the original with your code, ran the macro and got a run time error "424" Object required.

When I run debug this is the line that needs corrected somehow:
Set sht = ShtNames(i)

Any suggested corrections to fix this?

Paul_Hossler
03-26-2010, 05:36 PM
The Array ShtNames() contrains strings

Try

Set sht = Worksheets(ShtNames(i))

You might have to use

Set sht = Worksheets(Cstr(ShtNames(i)))

since sometimes Excel really want a true String, so you have to convert

Paul

jasonr704
03-26-2010, 06:03 PM
This one worked:
Set sht = Worksheets(ShtNames(i))

Thank you very much!
Bunch of really really smart guys here!