Created
April 20, 2016 18:13
-
-
Save danwagnerco/92cdc58e5dde87eeb06a6f2fa9d1b1f0 to your computer and use it in GitHub Desktop.
This file contains hidden or bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Option Explicit | |
Public Sub CombineDataFromAllSheets() | |
Dim wksSrc As Worksheet, wksDst As Worksheet | |
Dim rngSrc As Range, rngDst As Range | |
Dim lngLastCol As Long, lngSrcLastRow As Long, lngDstLastRow As Long | |
'Notes: "Src" is short for "Source", "Dst" is short for "Destination" | |
'Set references up-front | |
Set wksDst = ThisWorkbook.Worksheets("Import") | |
lngDstLastRow = LastOccupiedRowNum(wksDst) '<~ defined below (and in Toolbelt)! | |
lngLastCol = LastOccupiedColNum(wksDst) '<~ defined below (and in Toolbelt)! | |
'Set the initial destination range | |
Set rngDst = wksDst.Cells(lngDstLastRow + 1, 1) | |
'Loop through all sheets | |
For Each wksSrc In ThisWorkbook.Worksheets | |
'Make sure we skip the "Import" destination sheet! | |
If wksSrc.Name <> "Import" Then | |
'Identify the last occupied row on this sheet | |
lngSrcLastRow = LastOccupiedRowNum(wksSrc) | |
'Store the source data then copy it to the destination range | |
With wksSrc | |
Set rngSrc = .Range(.Cells(2, 1), .Cells(lngSrcLastRow, lngLastCol)) | |
rngSrc.Copy | |
rngDst.PasteSpecial Paste:=xlPasteValues '<~ change from original | |
rngDst.PasteSpecial Paste:=xlPasteFormats '<~ change from original | |
End With | |
'Redefine the destination range now that new data has been added | |
lngDstLastRow = LastOccupiedRowNum(wksDst) | |
Set rngDst = wksDst.Cells(lngDstLastRow + 1, 1) | |
End If | |
Next wksSrc | |
End Sub | |
''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''' | |
'INPUT : Sheet, the worksheet we'll search to find the last row | |
'OUTPUT : Long, the last occupied row | |
'SPECIAL CASE: if Sheet is empty, return 1 | |
Public Function LastOccupiedRowNum(Sheet As Worksheet) As Long | |
Dim lng As Long | |
If Application.WorksheetFunction.CountA(Sheet.Cells) <> 0 Then | |
With Sheet | |
lng = .Cells.Find(What:="*", _ | |
After:=.Range("A1"), _ | |
Lookat:=xlPart, _ | |
LookIn:=xlFormulas, _ | |
SearchOrder:=xlByRows, _ | |
SearchDirection:=xlPrevious, _ | |
MatchCase:=False).Row | |
End With | |
Else | |
lng = 1 | |
End If | |
LastOccupiedRowNum = lng | |
End Function | |
''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''''' | |
'INPUT : Sheet, the worksheet we'll search to find the last column | |
'OUTPUT : Long, the last occupied column | |
'SPECIAL CASE: if Sheet is empty, return 1 | |
Public Function LastOccupiedColNum(Sheet As Worksheet) As Long | |
Dim lng As Long | |
If Application.WorksheetFunction.CountA(Sheet.Cells) <> 0 Then | |
With Sheet | |
lng = .Cells.Find(What:="*", _ | |
After:=.Range("A1"), _ | |
Lookat:=xlPart, _ | |
LookIn:=xlFormulas, _ | |
SearchOrder:=xlByColumns, _ | |
SearchDirection:=xlPrevious, _ | |
MatchCase:=False).Column | |
End With | |
Else | |
lng = 1 | |
End If | |
LastOccupiedColNum = lng | |
End Function |
Sign up for free
to join this conversation on GitHub.
Already have an account?
Sign in to comment