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!
 

Excel Facts

Pivot Table Drill Down
Double-click any number in a pivot table to create a new report showing all detail rows that make up that number
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
 
Upvote 0
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
 
Upvote 0
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:
Upvote 0
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
 
Upvote 0

Forum statistics

Threads
1,214,523
Messages
6,120,042
Members
448,940
Latest member
mdusw

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