+ Reply to Thread
Results 1 to 3 of 3

Copy Varying Range Sizes from Multiple Sheets to Main Sheet

Hybrid View

  1. #1
    Registered User
    Join Date
    01-28-2010
    Location
    Denver, Co
    MS-Off Ver
    Excel 2003
    Posts
    4

    Copy Varying Range Sizes from Multiple Sheets to Main Sheet

    Hi Guru's

    I have couple of issues and questions with this Macro.

    1.) Is there a way to change the reference point (starting point) when it copies the information from each sheet. I am having problems because it starts at "A1" on each sheet and really need it to start at "B1"

    2.) Data (row) fails to copy if I have missing data in column A even though I might have data in consecutive columns. Is there a way to make the count rows function look at cells A:F?

    I have attached a file, that will probably explain better my situation and it contains the macro in quesiton.

    Any help would be much appreciated.

    -Wesley
    Attached Files Attached Files

  2. #2
    Registered User
    Join Date
    12-27-2009
    Location
    Paris, France
    MS-Off Ver
    Excel 2003
    Posts
    64

    Re: Copy Varying Range Sizes from Multiple Sheets to Main Sheet

    Hello,

    I reprogrammed your code.*Try my version.

    Sub test_pmo()
    Dim SUMMA As Worksheet
    Dim S As Worksheet
    Dim C As Range
    Dim R As Range
    Dim i&
    Dim j&
    Dim k&
    Dim cpt&
    Dim Lig&
    Dim var
    Dim T()
    Dim myProduct
    Dim Couleurs
    Couleurs = Array(34, 35, 36, 40)
    Set SUMMA = Sheets("Summary")
    For Each myProduct In Array("Fruit", "Vegetables", "Breads", "Meat")
      For Each S In ActiveWorkbook.Worksheets
        If Not S Is SUMMA And S.Name <> "Exposé" Then
          Set C = S.Range("A:F").Find(myProduct, LookIn:=xlValues)
          If Not C Is Nothing Then
            Set R = C.CurrentRegion
            If S.Name <> "Template" Then Set R = R.Resize(R.Rows.Count - (C.Row - R.Row + 2)).Offset(C.Row - R.Row + 2, 0)
            var = R
            cpt& = 0
            Erase T
            For i& = 1 To UBound(var, 1)
              If var(i&, 1) <> "" Then
                cpt& = cpt& + 1
                ReDim Preserve T(1 To 3, 1 To cpt&)
                For j& = 1 To 3
                  T(j&, cpt&) = var(i&, j&)
                Next j&
              End If
            Next i&
            Lig& = SUMMA.[a65536].End(xlUp).Row + 1
            Set R = SUMMA.Range(SUMMA.Cells(Lig&, 1), SUMMA.Cells(UBound(T, 2) + Lig& - 1, UBound(T, 1)))
            R = Application.WorksheetFunction.Transpose(T)
            If S.Name = "Template" Then
              R.Interior.ColorIndex = Couleurs(k&)
              Set R = SUMMA.Range("a" & Lig& & ":c" & Lig& & "")
              R.Font.Bold = True
              BordersRange R
              Set R = R.Offset(1, 0)
              R.HorizontalAlignment = xlCenter
              BordersRange R, True
            Else
              BordersRange R, True
              Set R = R.Resize(R.Rows.Count, R.Columns.Count - 2).Offset(0, 1)
              R.NumberFormat = "$# ##0.00"
              R.HorizontalAlignment = xlCenter
              R.Offset(0, 1).HorizontalAlignment = xlCenter
            End If
          End If
        End If
      Next S
      k& = k& + 1
    Next myProduct
    End Sub
    
    Sub BordersRange(R As Range, Optional Inside As Boolean)
    Dim Fin&
    Dim i&
    Fin& = 10
    If Inside Then Fin& = 12
    On Error Resume Next
    For i& = 7 To Fin&
      R.Borders(i&).LineStyle = xlContinuous
    Next i&
    End Sub

    Best regards.

    PMO
    Patrick Morange

  3. #3
    Forum Moderator Leith Ross's Avatar
    Join Date
    01-15-2005
    Location
    San Francisco, Ca
    MS-Off Ver
    2000, 2003, & 2010
    Posts
    23,259

    Re: Copy Varying Range Sizes from Multiple Sheets to Main Sheet

    Hello Wester,

    I made some changes to your macro and added a button on "Sheet1" to run it. The attached workbook has the changes already added to it.
    Sub test()
    
    Dim myWS As Worksheet, writeRow As Long
    Dim myProduct, prodFind As Range
    Dim R As Long
    Dim Rng As Range
    
    writeRow = 2
    For Each myProduct In Array("Fruit", "Vegetables", "Breads", "Meat")
    
        For Each myWS In ActiveWorkbook.Worksheets
            
            If myWS.Name <> "Summary" Then
            
                Set Rng = myWS.Range("B2", myWS.Cells(Rows.Count, "B").End(xlUp))
                Set Rng = Rng.Offset(0, -1).Resize(ColumnSize:=6)
                
                Set prodFind = Rng.Columns(1).Cells.Find(myProduct, , LookIn:=xlValues, LookAt:=xlWhole, SearchOrder:=xlByColumns, SearchDirection:=xlNext, MatchCase:=False)
    
                If Not prodFind Is Nothing Then
    
                    With prodFind.CurrentRegion
                      R = 2
                      If .Row = 1 Then R = 3
                      .Offset(R, 0).Resize(.Rows.Count - R, .Columns.Count).Copy _
                         Sheets("Summary").Range("A" & writeRow)
                      writeRow = writeRow + .Rows.Count - R
                    End With
                    
                End If
                
            End If
            
        Next myWS
        
      writeRow = writeRow + 1
      
    Next myProduct
    
    End Sub
    Attached Files Attached Files
    Last edited by Leith Ross; 01-30-2010 at 03:16 PM.
    Sincerely,
    Leith Ross

    Remember To Do the Following....

    1. Use code tags. Place [CODE] before the first line of code and [/CODE] after the last line of code.
    2. Thank those who have helped you by clicking the Star below the post.
    3. Please mark your post [SOLVED] if it has been answered satisfactorily.


    Old Scottish Proverb...
    Luathaid gu deanamh maille! (Rushing causes delays!)

+ Reply to Thread

Thread Information

Users Browsing this Thread

There are currently 1 users browsing this thread. (0 members and 1 guests)

Tags for this Thread

Bookmarks

Posting Permissions

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

Search Engine Friendly URLs by vBSEO 3.6.0 RC 1