finding Last row ??

Michael M

Well-known Member
Joined
Oct 27, 2005
Messages
21,898
Office Version
  1. 365
  2. 2019
  3. 2013
  4. 2007
Platform
  1. Windows
Hi All
I thought this would be a lounge type question.
I have noticed over some time that many users have a different spin on finding the last row.
I was wondering which is the fastest, most efficient, etc.

I use:
Code:
Lrow=Cells(Rows.Count,"A").End(xlUp).Row

while others use:
Code:
LR = Range("A" & Rows.Count).End(xlUp).Row
and some are still using the range reference of 65000, or 1 million now.

It probably makes bugger all difference, but it has been *****ing my curiosity

Regards
Michael M
 

Excel Facts

How to total the visible cells?
From the first blank cell below a filtered data set, press Alt+=. Instead of SUM, you will get SUBTOTAL(9,)
I suggest you search (Google? or the board?)for how to time a macro and test it out. It's a good learning exercise.
lenze
FYI: Bill has this in the book Excel Gurus Gone Wild
 
Thanks Lenze
I was more interested in the reasoning behind the different ways you guys find the last row.
In the 2 examples I mentioned, both are used by very experienced and skilled MVP's.
I was curious as to why one MVP would use 1 example over the other.
Maybe I'm just having a quiet day....what do they say about idle minds, or is it hands.


Regards
Michael M
 
Just for interest sake
sample 2 was 1.01 secs slower than sample 1, in my model.

Regards
Michael M
 
Actually, it's a matter of style and almost always goes back to how we learned!! A good example is Smitty and myself. We're good internet friends via MrExcel, but in many cases we don't code anything alike. Neither one of us thinks the other is wrong. We just do it differently. In fact, the difference can be obvious. Recently, I got a PM from a user with some code that they said I had posted somewhere, but I knew immediately it wasn't mine because to my knowledge I had NEVER done that task that way. But, I wrote back and told the guy(gal?) that I was 95% sure it was written by Smitty, and it was.

lenze

BTW: I am suprised the difference is that big
 
OK....that's what I was looking at.
I had seen a number of things done differently, but this was a simple one liner, so I chose it, as it seems to be one of things we almost always do in a macro.
I have learned that you guys all approach things a little differently. If you didn't, we woudln't need a Mr Excel Forum.
Thanks for the comments.
Regards
Michael M
 
Method utilising Rows.Count is preferred given it is version independent.
Use of 65536 is open to error in 2007 and beyond, use of 1m is only viable in 2007 onwards.
Use of Range / Cells is generally a case of preference (I tend to use Cells myself).
Also worth pointing out that the variable if explicitly declared should be declared as Long.
 
In terms of Cells property vs Range property
Code:
Cells(Rows.Count,"A").
vs.
Code:
Range("A" & Rows.Count).
There are clear situations when one would be required over the other, but I'd use either here.

More important is knowing some limitations of using Range.End() property to determine the last used cell. It's quick but it only works in simple situations. You can only use it on a single column so, short of looping through every column, it's no good if you want to find the last used row of a worksheet, and, if the last cell in the column hidden (say filtering is applied) then it will return the *wrong* result.
 
Colin,

How would one find the real LRw in filtered datasets?

Code:
Sub foo2()
Dim lrw As Long
lrw = Sheets(1).Range(Cells(1, 1), Cells(Rows.Count, Columns.Count)).Find(what:="*", searchdirection:=xlPrevious, searchorder:=xlByRows).Row
Debug.Print lrw
End Sub

This finds the real LRw if hidden, but not if filtered.
 
I guess there are various options, perhaps:

Code:
Sub foo2()
Dim lrw As Long
With Sheets(1)
    If .FilterMode Then lrw = .AutoFilter.Range.Row + .AutoFilter.Range.Rows.Count - 1
    lrw = Application.Max(lrw,.Cells.Find(what:="*", searchdirection:=xlPrevious, searchorder:=xlByRows).Row)
End With
Debug.Print lrw
End Sub
 

Forum statistics

Threads
1,224,823
Messages
6,181,175
Members
453,021
Latest member
Justyna P

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