Code to select all used cells on a sheet

richanor

Active Member
Joined
Apr 8, 2006
Messages
291
Hi, I've combined a few bits of code from this board to come up with a macro that will combine a number of workbooks from the same directory into one master workbook. I just need help with selecting the range.

I am trying to select all used cells on the active sheet, except the column headings (Column Headings are rows 1-10, main data starts at row 11). At the moment my code for selecting the range is:

ws.Range("A11:E17").Copy

because in that worksheet there happend to be 7 rows of data. It will always be columns A:E, starting at row 11, but the number of rows will vary. Can somebody help me out with the code I need?

Thanks

Rich
 

Excel Facts

Shade all formula cells
To shade all formula cells: Home, Find & Select, Formulas to select all formulas. Then apply a light fill color.
Try this:
Code:
LastRow = Rows(ws.UsedRange.Row + ws.UsedRange.Rows.Count - 1).Row
ws.Range("A11:E" & LastRow).Copy
 
Upvote 0
Try:
Code:
ws.Range("A11:E" & Range("A" & Rows.Count).End(xlUp).Row).Copy
 
Upvote 0
@mumps:

Your code will find the row of the last used cell in column A. There might be used cells beyond that row in other columns.
 
Upvote 0
Try this
Code:
    Dim c As Range
    
    With Sheets("Sheet1")
        Set c = .Range("A:E").Find("?*", after:=.Cells(1, 1), LookIn:=xlValues, searchorder:=xlByRows, searchdirection:=xlPrevious)
        Set c = Range(c, .Range("A11"))
        Set c = Application.Intersect(c.EntireRow, .Range("A:E"))
    End With
 
Last edited:
Upvote 0
@Tetra201: You are correct. I assumed that the last used cell in column A was the end of the data. If this is not the case then this should work:
Code:
 ws.Range("A11:E" & Cells.Find("*", SearchOrder:=xlByRows, SearchDirection:=xlPrevious).Row).Copy
 
Upvote 0
Guys, thanks so much for the help. I know it's not directly related to the original question, but having now inserted your code I have another problem:

When I run the macro, I get a "Compile Error, Variable Not Defined" error at the Nextrow = SumarySheet........ line. Can anybody help me out as to why this would be? I did not write any of this code, I patched it together from bits I found on this board, and to be honest, I don't really understand it very well!

Many thanks in advance.

Rich

Code:
Option Explicit

Const FolderPath As String = "C:\Admin\Annual Leave"


Sub MergeAllWorkbooks()
    Dim SummarySheet As Worksheet
    Dim FolderPath As String
    Dim fileName  As String
    Dim ws As Worksheet
    Dim counter As Long
    
    Set SummarySheet = ThisWorkbook.Sheets("Annual Leave Tracker")
    
    fileName = Dir(FolderPath & "*.xl*")
    
    Application.ScreenUpdating = False

    Do While fileName <> ""

        With Workbooks.Open(FolderPath & fileName)
        
            Set ws = Nothing
            On Error Resume Next
            Set ws = .Sheets("Tracker")
            On Error GoTo 0
            
            If Not ws Is Nothing Then
                
                NextRow = SummarySheet.Range("A" & Rows.Count).End(xlUp).Row + 1
            

                LastRow = Rows(ws.UsedRange.Row + ws.UsedRange.Rows.Count - 1).Row
                ws.Range("A11:E" & LastRow).Copy
                SummarySheet.Range("A" & NextRow).PasteSpecial Paste:=xlPasteValues
                                
                counter = counter + 1
            End If
            
            .Close SaveChanges:=False
        End With
    
        fileName = Dir()
    Loop
    Application.ScreenUpdating = True
    
    SummarySheet.Columns.AutoFit
    MsgBox counter & " workbooks consolidated. ", , "Consolidation Complete"
    
End Sub
 
Upvote 0
Try placing
Code:
Dim LastRow as Long
at the beginning of your macro.
 
Upvote 0
... When I run the macro, I get a "Compile Error, Variable Not Defined" error at the Nextrow = SumarySheet........ line.
You have Option Explicit at the beginning of your code.
This means that all variables must be explicitly declared.
So, you have to add the following to your declaration section:
Code:
Dim NextRow As Long
Dim LastRow As Long
 
Last edited:
Upvote 0

Forum statistics

Threads
1,213,546
Messages
6,114,256
Members
448,557
Latest member
richa mishra

We've detected that you are using an adblocker.

We have a great community of people providing Excel help here, but the hosting costs are enormous. You can help keep this site running by allowing ads on MrExcel.com.
Allow Ads at MrExcel

Which adblocker are you using?

Disable AdBlock

Follow these easy steps to disable AdBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the icon in the browser’s toolbar.
2)Click on the "Pause on this site" option.
Go back

Disable AdBlock Plus

Follow these easy steps to disable AdBlock Plus

1)Click on the icon in the browser’s toolbar.
2)Click on the toggle to disable it for "mrexcel.com".
Go back

Disable uBlock Origin

Follow these easy steps to disable uBlock Origin

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back

Disable uBlock

Follow these easy steps to disable uBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back
Back
Top