Try this
There are two sheets that I don't want it to copy
Add the two sheet names in the array (replace sheet1 and sheet2)
If IsError(Application.Match(sh.Name, _
Array(DestSh.Name, "Information", "Sheet1", "Sheet2"), 0)) Then
This eample copy the first row of the first sheet as header row
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 "Total" if it exist
Application.DisplayAlerts = False
On Error Resume Next
ActiveWorkbook.Worksheets("Total").Delete
On Error GoTo 0
Application.DisplayAlerts = True
'Add a worksheet with the name "Total"
Set DestSh = ActiveWorkbook.Worksheets.Add
DestSh.Name = "Total"
'loop through all worksheets and copy the data to the DestSh
For Each sh In ActiveWorkbook.Worksheets
'Loop through all worksheets execpt the Total worksheet and the
'Information worksheet, you can ad more sheets to the array if you want.
If IsError(Application.Match(sh.Name, _
Array(DestSh.Name, "Information", "Sheet1", "Sheet2"), 0)) Then
'Copy the header row one time
If DestSh.Range("A1") = "" Then
sh.Rows(1).Copy DestSh.Range("A1")
End If
'Find the last row with data on the DestSh
Last = LastRow(DestSh)
'Fill in the range that you want to copy
'Set CopyRng = sh.Rows("11:58")
Set CopyRng = sh.Rows("2:5")
'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
'copy the values
With CopyRng
DestSh.Cells(Last + 1, "A").Resize(.Rows.Count, .Columns.Count).Value = .Value
End With
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
End Function