How does usedrange.rows.count work?

RiaM

Board Regular
Joined
Jun 5, 2009
Messages
67
Hi

Can someone please explain to me how the following statements work?

LastRow = ActiveSheet.UsedRange.Rows.Count
LastCol = ActiveSheet.UsedRange.Columns.Count

I thought what it does was went into the active sheet, scanned the cells for contents, and returned the highest row or column, respectively.

I've used it in several of my macro's and this is what seems to happen. However, I just wrote one now, where cells that contain contents start at row 12 and end at row 15, but for some reason "LastRow" is being calculated to be 4. I'm having a similar error with LastCol

Blue skies!
 

RoryA

MrExcel MVP, Moderator
Joined
May 2, 2008
Messages
34,349
Office Version
365, 2019, 2016, 2010
Platform
Windows, MacOS
That's not an error. If the first 11 rows are blank they don't form part of the Usedrange, and the number of rows in your usedrange is indeed 4. You should also be aware that the usedrange property is not 100% reliable anyway - it can overstate the range. My preference is to use a function like:
Code:
Public Function LastCellInSheet(Optional wks As Worksheet) As Range
   ' Returns the cell at the bottom right corner of the sheet's real used range
   Dim lngLastCol As Long, lngLastRow As Long
   lngLastCol = 1
   lngLastRow = 1
   On Error Resume Next
   If wks Is Nothing Then Set wks = ActiveSheet
   With wks.UsedRange
      lngLastCol = .Cells.Find(what:="*", after:=.Cells(1), _
              SearchOrder:=xlByColumns, _
              SearchDirection:=xlPrevious, searchformat:=False).Column
      lngLastRow = .Cells.Find(what:="*", after:=.Cells(1), _
              SearchOrder:=xlByRows, _
              SearchDirection:=xlPrevious, searchformat:=False).Row
   End With
   Set LastCellInSheet = wks.Cells(lngLastRow, lngLastCol)
End Function
 

Richard Schollar

MrExcel MVP
Joined
Apr 19, 2005
Messages
23,707
Hi

It counts the number of rows/columns within the UsedRange - if your data starts at row 12 and extends to row 15 then that is only 4 rows' worth of data (12,13,14 and 15) - if you were then to place something in row 1, you would then get 15 rows' of data.

To calculate the last row of data it's better to avoid UsedRange at all:

Code:
Dim lngLastRow As Long
 
lngLastRow = Cells.Find(What:="*",LookIn:=xlValues,SearchDirection:=xlPrevious,SearchOrder:=xlByRows).Row
 

jbeaucaire

Well-known Member
Joined
May 8, 2002
Messages
6,012
I have similar dissatisfaction when trying to use UsedRange in that manner. On a sheet by sheet basis, I choose the columns and rows I will use to "spot" the last row (LR) and last column (LC) respectively for my code.

Using your example, I may know the data starts in row 12, but I also know row 13 is the best row for seeing how far to the right the data goes, because that's my header row. And Column B has all my "ID CODES" in it for each row of data. So the code I would use in this situation to spot LR and LC is:

Code:
Sub MacroExample()
Dim LR As Long, LC As Long
LR = Cells(Rows.Count, 2).End(xlUp).Row         'Last row of data in col B
LC = Cells(13, Columns.Count).End(xlUp).Column  'Last col of date in row 13

...etc
End Sub
 
Last edited:

jbeaucaire

Well-known Member
Joined
May 8, 2002
Messages
6,012
OOPS, correction in my LC code:
Rich (BB code):
Sub MacroExample()
Dim LR As Long, LC As Long
LR = Cells(Rows.Count, 2).End(xlUp).Row         'Last row of data in col B
LC = Cells(13, Columns.Count).End(xlToLeft).Column  'Last col of date in row 13

...etc
End Sub
 

Forum statistics

Threads
1,082,126
Messages
5,363,319
Members
400,725
Latest member
excelingtolearn

Some videos you may like

This Week's Hot Topics

  • populate from drop list with multiple tables
    Hi All, i have a drop list that displays data, what i want is when i select one of those from the list to populate text from different tables on...
  • Find list of words from sheet2 in sheet1 before a comma and extract text vba
    Hi Friends, Trying to find the solution on my task. But did not find suitable one to the need. Here is my query and sample file with details...
  • Dynamic Formula entry - VBA code sought
    Hello, really hope one of you experts can help with this - i've spent hours on this and getting no-where. .I have a set of data (more rows than...
  • Listbox Header
    Have a named range called "AccidentsHeader" Within my code I have: [CODE]Private Sub CommandButton1_Click() ListBox1.RowSource =...
  • Complex Heat Map using conditional formatting
    Good day excel world. I have a concern. Below link have a list of countries that carries each country unique data. [URL...
  • Conditional formatting
    Hi good morning, hope you can help me please, I have cells P4:P54 and if this cell is equal to 1 then i want row O to say "Fully Utilised" and to...
Top