SYMPTOMS
In Microsoft Visual Basic for Applications, the
UsedRange property of the worksheet returns an incorrect address for the actual used range of the worksheet. If you attempt to use the
Select method with the address returned by the
UsedRange property, you receive the following error message:
Run-time error '1004':
Select method of range class failed.
And the macro fails.
WORKAROUND
Microsoft provides programming examples for illustration only, without warranty either expressed or implied. This includes, but is not limited to, the implied warranties of merchantability or fitness for a particular purpose. This article assumes that you are familiar with the programming language that is being demonstrated and with the tools that are used to create and to debug procedures. Microsoft support engineers can help explain the functionality of a particular procedure, but they will not modify these examples to provide added functionality or construct procedures to meet your specific requirements.
To return the correct used range on the worksheet, use the
SpecialCells method instead of the
UsedRange property. The following sample macro returns the used range of the worksheet.
NOTE: The sample macro below finds cells that contain data, such as text, values, and formulas. It does not find cells that only contain formatting and no real data.
Sub MyUsedRange()
Dim ar As Range, r As Double, c As Integer, tr As Double, tc As Integer
Dim ur As Range, fr As Double, fc As Integer, tfr As Double, tfc As Integer
On Error Resume Next
fc = ActiveSheet.Columns.Count
fr = ActiveSheet.Rows.Count
Set ur = Union(ActiveSheet.UsedRange.SpecialCells(xlCellTypeConstants), _
ActiveSheet.UsedRange.SpecialCells(xlCellTypeFormulas))
If Err.Number = 1004 Then
Err.Clear
Set ur = ActiveSheet.UsedRange.SpecialCells(xlCellTypeConstants)
End If
If Err.Number = 1004 Then
Err.Clear
Set ur = ActiveSheet.UsedRange.SpecialCells(xlCellTypeFormulas)
End If
If Err.Number = 0 Then
For Each ar In ur.Areas
tr = ar.Range("A1").Row + ar.Rows.Count - 1
tc = ar.Range("A1").Column + ar.Columns.Count - 1
If tc > c Then c = tc
If tr > r Then r = tr
tfr = ar.Range("A1").Row
tfc = ar.Range("A1").Column
If tfc < fc Then fc = tfc
If tfr < fr Then fr = tfr
Next
Range(Cells(fr, fc), Cells(r, c)).Select
ElseIf Err.Number = 1004 Then
Range("A1").Select
End If
End Sub