No. CurrentRegion is specific to a single area. (an area in this instance
is filled cells that do not have an entirely blank row or column across
their width or height.)
If you used a cell in Area1 and did Currentregion, it would return Area1
UsedRange reflects the cells that Excel stores information about (it is
always a single rectangular range). If Excel does not need to store
information about cells, it does not (so while you see 65536 rows, those
past the used range are vitual until needed). So usedrange will never be
less that the total range of filled cells, but it may be larger (the problem
you are having).
If you want to find the "RealLastCell with data:"
In a thread subject Re: Change What Excel Believes Is The Last Cell
In Microsoft.Public.Excel.Programming on October 15, 1999
This was posted by John Green
"The following code will find the last row and last column that contain data
on the active worksheet:"
Sub GetRealLastCell()
Dim RealLastRow As Long
Dim RealLastColumn As Long
Range("A1").Select
On Error Resume Next
RealLastRow = _
Cells.Find("*", [A1], , , xlByRows, xlPrevious).Row
RealLastColumn = _
Cells.Find("*", [A1], , , xlByColumns, xlPrevious).Column
Cells(RealLastRow, RealLastColumn).Select
End Sub
[ the cell selected is at the intersection of the last row and last column
and may be empty, so you can use each result independently]
This is a version posted by David Chazin with some additional error checking
Sub LastCell_Select()
'David Chazin 05-Mar-1999
'Selects the cell at the bottom-right corner of the used area
' of the currently selected worksheet.
Range(LastCell_Get()).Select
End Sub
Function LastCell_Get() As String
'David Chazin -- September 1999.
'Returns the Address (e.g. "$AW$235") of the cell at the
' bottom-right corner of the used area of the currently
' selected worksheet. Returns "" if the worksheet is empty.
' Thanks to Dave Braden for the idea of trapping for an
' empty worksheet. (This is not the way he would implement
' it, but the idea itself is his).
On Error GoTo LastCell_Get_ErrorHandler
If Range("A1").SpecialCells(xlLastCell).Value <> "" Then
LastCell_Get = Range("A1").SpecialCells(xlLastCell).Address()
Else
LastCell_Get = _
Cells(Cells.Find("*", ActiveCell.SpecialCells(xlLastCell), , , _
xlByRows, xlPrevious).Row, _
Cells.Find("*", ActiveCell.SpecialCells(xlLastCell), , , _
xlByColumns, xlPrevious).Column).Address()
End If
Exit Function
LastCell_Get_ErrorHandler:
If Err.Number = 91 Then
'If the worksheet is empty....
LastCell_Get = ""
Else
Call MsgBox("Error #" & Err.Number & " was generated by " & _
Err.Source & ": " & Err.Description, vbOKOnly + vbExclamation, _
"LastCell_Get()", Err.HelpFile, Err.HelpContext)
End If
End Function
Regards,
Tom Ogilvy