Consulting

Results 1 to 3 of 3

Thread: Consolidation of 5 worksheets into a single master sheet

  1. #1
    VBAX Newbie
    Joined
    Apr 2014
    Posts
    2
    Location

    Consolidation of 5 worksheets into a single master sheet

    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

  2. #2
    VBAX Sage
    Joined
    Apr 2007
    Location
    United States
    Posts
    8,724
    Location
    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
    ---------------------------------------------------------------------------------------------------------------------

    Paul


    Remember: Tell us WHAT you want to do, not HOW you think you want to do it

    1. Use [CODE] ....[/CODE ] Tags for readability
    [CODE]PasteYourCodeHere[/CODE ] -- (or paste your code, select it, click [#] button)
    2. Upload an example
    Go Advanced / Attachments - Manage Attachments / Add Files / Select Files / Select the file(s) / Upload Files / Done
    3. Mark the thread as [Solved] when you have an answer
    Thread Tools (on the top right corner, above the first message)
    4. Read the Forum FAQ, especially the part about cross-posting in other forums
    http://www.vbaexpress.com/forum/faq...._new_faq_item3

  3. #3
    VBAX Newbie
    Joined
    Apr 2014
    Posts
    2
    Location

    Thanks

    Thanks Paul.

    Your suggestion has worked perfectly.

    Thank you for your time and effort.

    Much appreciated

    Cheers,


    Quote Originally Posted by Paul_Hossler View Post
    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

Posting Permissions

  • You may not post new threads
  • You may not post replies
  • You may not post attachments
  • You may not edit your posts
  •