VBA - advanced videos | Excel VBA Part 45 - Finding the Last Used Row, Column and Cell

Posted by Andrew Gould on 25 October 2016

There are several techniques you can use in VBA to find the last row, column or cell in a worksheet. This video shows you a range of options including using the End and Offset properties; the CurrentRegion property of a Range and the UsedRange property of a Worksheet; the LastCell option of the SpecialCells method and, finally, the trusty Find method.

You can increase the size of the video:

Full screen mode for YouTube

You can view the video in full screen mode as shown on the left, using the icon at the bottom right of the frame.

You can also increase the quality of the video:

Changing resolution

You can improve the resolution of the video using another icon at the bottom right of the frame. This will slow down the connection speed, but increase the display and sound quality. This icon only becomes visible when you start playing the video.

Finally, if nothing happens when you play the video, check that you're not using IE in compatibility view.

This page has 2 threads Add post
15 Oct 18 at 10:23

Brilliant!

Thanks for your detailed explanation, finally got it.

 

 

15 Oct 18 at 10:30

No problem, glad we got there!

13 Oct 18 at 08:51

Hi, I have a query with my code and hope you can help.  I use this function to find the last column on a particular worksheet that contains data:

Public Function LCol(ByRef wks As Worksheet) As Long

    On Error GoTo Correction

        With wks
       
            LCol = .Cells.Find(What:="*", _
                               After:=.Cells(Rows.Count, Columns.Count), _
                               SearchDirection:=xlPrevious, _
                               SearchOrder:=xlByColumns).Column
           
        End With
   
        GoTo Exitpoint
   
Correction:
        LCol = 1

Exitpoint:

    On Error GoTo 0

End Function

My workbook has two worksheets: Sheet1 and Sheet2.  Sheet1 contains a value in cell J10.

I have a Worksheet_Deactivate() event on Sheet1:

Option Explicit

Private Sub Worksheet_Deactivate()
   
    Dim a As Long
   
    a = FnLastRow.LCol(wks:=Me)
   
End Sub

So when I move off Sheet1 to go to Sheet2, the code above assigns the value of 10 to the variable a because the last column of data on Sheet1 is in column J.

All is good.

Now if my workbook also contains a chart sheet (that contains a chart only) and I move from Sheet1 to the chart sheet, the code goes to the function BUT it seems to assign a value of LCol of 1, ie it errors.

What is wrong?

Thanks

15 Oct 18 at 08:11

In the Find method you've referred to the Rows and Columns properties.  These properties implicitly apply to the active sheet.  If you move from Sheet1 to a chart, the active sheet does not have a Rows or Columns property.  You can fix this easily enough by explicitly stating that you want to return the Rows and Columns property of the worksheet object that you have passed to the function:

LCol = .Cells.Find(What:="*", _
                               After:=.Cells(.Rows.Count, .Columns.Count), _
                               SearchDirection:=xlPrevious, _
                               SearchOrder:=xlByColumns).Column

I hope that helps!

15 Oct 18 at 08:43

Andrew,

Thanks for your reply.

The explanation to your solution is what I had initially thought but why is it that if I move from Sheet1 to Sheet2, where Sheet1 has a value in cell J10, it works?

Because according to your explanation, my initial Find would be refering to the sheet it's moving TO, not FROM?

 

Andrew G  
15 Oct 18 at 10:14

Don't worry!  At the point the code in Deactivate method runs, the active sheet is the one that you have moved TO, Sheet2 in this case.  You can test this easily enough by adding a Debug.Print statement to the procedure:

Private Sub Worksheet_Deactivate()

    Debug.Print ActiveSheet.Name

If you take out the With block in your code, it's easier to see the explicit references you've made to the sheet you're moving FROM (emphasised in bold below):

 LCol = wks.Cells.Find(What:="*", _
                               After:=wks.Cells(Rows.Count, Columns.Count), _
                               SearchDirection:=xlPrevious, _
                               SearchOrder:=xlByColumns).Column

So, you're applying the Find method to cells on the worksheet you've moved FROM.  You're beginning the search After a cell on the worksheet you've moved FROM.

You haven't stated which worksheet you want the Rows and Columns properties to apply to, which means that they will use the active sheet, i.e. the sheet you're moving TO.  When you move to a chart sheet this fails because a chart sheet doesn't have a Rows or Columns property.  When you move to another worksheet you're returning the number of rows and columns on the sheet you have moved TO.  Because these numbers are the same on any worksheet the code will still work.

duggie  
15 Oct 18 at 10:00

Sorry to dwell on this.

If this code is on sheet1:

Private Sub Worksheet_Deactivate()

and I move from sheet1 to sheet2, which is the active sheet? Sheet1 or Sheet2?

 

 

Andrew G  
15 Oct 18 at 09:28

Not quite - you had already applied the Find method to cells on the worksheet whose reference you passed to the function:

LCol = .Cells.Find(What:="*", _

If you had written this:

LCol = Cells.Find(What:="*", _

then the Find method would apply to the worksheet that was currently active.

You're using the Rows.Count and Columns.Count properties simply to return the number of rows and columns on a worksheet:

After:=.Cells(Rows.Count, Columns.Count), _

Rows.Count will return 1048576 and Columns.Count will return 16384 regardless of which worksheet you reference.  Both properties will fail if you apply them to a chart sheet.