PDA

View Full Version : Consolidation of 5 worksheets into a single master sheet



dchirrav
04-30-2014, 04:52 PM
Hi All,
I am using a piece of code which I have picked up from this site which consolidates mulitple worksheets into a single mastersheet. I realised there is a small glitch in the code.

The worksheet I am using has the same header for all of them. In case one of the worksheet is blank with no data but only the header wehn I run the macro and create the Master sheet the header of the blank worksheet gets created in the master sheet.

Here is the code:


Sub GenerateMasterSheet()
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

Here is the output I am getting if there are no blanks in the worksheets.



Name
City


China
Beijing


South Korea
Seoul


Germany
Berlin


UK
London


US
Washington


Brazil
Brasilia



Here is the output I am getting if there are blanks in the first worksheet






Name
City


Name
City


Germany
Berlin


UK
London


US
Washington


Brazil
Brasilia




























Any assistance will be much appreciated

Cheers,

Sam

Paul_Hossler
04-30-2014, 08:39 PM
I think adding the 2 marked statements will do what you want



If sht.Cells(1, 1).CurrentRegion.Rows.Count > 1 Then 'added

'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

End If 'added

dchirrav
05-01-2014, 06:47 PM
Thanks Paul.

Your suggestion has worked perfectly.

Thank you for your time and effort.

Much appreciated

Cheers,



I think adding the 2 marked statements will do what you want



If sht.Cells(1, 1).CurrentRegion.Rows.Count > 1 Then 'added

'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

End If 'added