Skip to content

Instantly share code, notes, and snippets.

@logic2design
Created August 29, 2020 10:28
Show Gist options
  • Save logic2design/ff0bec2e422522bd59fcf61d09900094 to your computer and use it in GitHub Desktop.
Save logic2design/ff0bec2e422522bd59fcf61d09900094 to your computer and use it in GitHub Desktop.
Copy a specified range from multiple worksheets into a master worksheet
'Fill in the range that you want to copy
'Set CopyRng = sh.Range("A1:G1")
Sub CopyRangeFromMultiWorksheets()
Dim sh As Worksheet
Dim DestSh As Worksheet
Dim Last As Long
Dim CopyRng As Range
With Application
.ScreenUpdating = False
.EnableEvents = False
End With
'Delete the sheet "RDBMergeSheet" if it exist
Application.DisplayAlerts = False
On Error Resume Next
ActiveWorkbook.Worksheets("RDBMergeSheet").Delete
On Error GoTo 0
Application.DisplayAlerts = True
'Add a worksheet with the name "RDBMergeSheet"
Set DestSh = ActiveWorkbook.Worksheets.Add
DestSh.Name = "RDBMergeSheet"
'loop through all worksheets and copy the data to the DestSh
For Each sh In ActiveWorkbook.Worksheets
If sh.Name <> DestSh.Name Then
'Find the last row with data on the DestSh
Last = LastRow(DestSh)
'Fill in the range that you want to copy
Set CopyRng = sh.Range("A1:G1")
'Test if there enough rows in the DestSh to copy all the data
If Last + CopyRng.Rows.Count > DestSh.Rows.Count Then
MsgBox "There are not enough rows in the Destsh"
GoTo ExitTheSub
End If
'This example copies values/formats, if you only want to copy the
'values or want to copy everything look at the example below this macro
CopyRng.Copy
With DestSh.Cells(Last + 1, "A")
.PasteSpecial xlPasteValues
.PasteSpecial xlPasteFormats
Application.CutCopyMode = False
End With
'Optional: This will copy the sheet name in the H column
DestSh.Cells(Last + 1, "H").Resize(CopyRng.Rows.Count).Value = sh.Name
End If
Next
ExitTheSub:
Application.Goto DestSh.Cells(1)
'AutoFit the column width in the DestSh sheet
DestSh.Columns.AutoFit
With Application
.ScreenUpdating = True
.EnableEvents = True
End With
End Sub
Function LastRow(sh As Worksheet)
On Error Resume Next
LastRow = sh.Cells.Find(What:="*", _
After:=sh.Range("A1"), _
Lookat:=xlPart, _
LookIn:=xlFormulas, _
SearchOrder:=xlByRows, _
SearchDirection:=xlPrevious, _
MatchCase:=False).Row
On Error GoTo 0
'Tips to change the examples
'In the example above I copy the range A1:G1 but you can also use
'Set CopyRng = sh.UsedRange
'To copy all cells with data on the sheet
'Set CopyRng = sh.Range("A1").CurrentRegion
'To copy the current region of cell A1
'The current region is a range bounded by any combination of blank rows and blank column
'Set CopyRng = sh.Rows("1")
'To copy a whole row or rows( use "1:8" then)
Sign up for free to join this conversation on GitHub. Already have an account? Sign in to comment