XL97: Offset of Nonadjacent Range Returns Incorrect Results

ID: Q172559


The information in this article applies to:
  • Microsoft Excel 97 for Windows


SYMPTOMS

In a Visual Basic for Applications subroutine in Microsoft Excel 97, the Offset property does not return the correct range for a range object that refers to nonadjacent cells. It returns one range of adjacent cells. This behavior is different in earlier versions of Microsoft Excel.


CAUSE

This behavior occurs when you run a Visual Basic subroutine and the following conditions are true:

  • You reference a range object for a range of nonadjacent cells.


  • -and-

  • You use the Offset property of the range object for the range of nonadjacent cells.



WORKAROUND

Microsoft provides programming examples for illustration only, without warranty either expressed or implied, including, but not limited to, the implied warranties of merchantability and/or fitness for a particular purpose. This article assumes that you are familiar with the programming language being demonstrated and the tools used to create and debug procedures. Microsoft support professionals 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 needs. If you have limited programming experience, you may want to contact the Microsoft fee-based consulting line at (800) 936-5200. For more information about the support options available from Microsoft, please see the following page on the World Wide Web:

http://www.microsoft.com/support/supportnet/overview/overview.asp
To work around this problem, reference each range of adjacent cells separately and then apply the Offset property. The following sample subprocedure uses this method:

  
   ' The following subroutine takes the selection and moves it over by one
   ' column to the right. The subroutine checks to see if the selected
   ' cells are adjacent or nonadjacent and handles the two situations
   ' differently.

   Sub Range_Offset_Select()

       ' Dimensions variables to be used.
       Dim NewRange As Range, singleArea As Range

       'Check to see if the selection is an adjacent selection.
       If Selection.Areas.Count = 1 Then

           ' Move the selection by one column to the right.
           Selection.Offset(0, 1).Select

       ' Else, if the selection is a nonadjacent selection...
       Else

           ' Sets the range object, Newrange to the offset by one column
           ' from the first adjacent area of the selection
           Set NewRange = Selection.Areas(1).Offset(0, 1)

           ' Starts a For/Each loop for each adjacent area of the
           ' selection.
           For Each singleArea In Selection.Areas
               Set NewRange = Union(NewRange, singleArea.Offset(0, 1))
           Next
           NewRange.Select

       End If

   End Sub 


STATUS

Microsoft has confirmed this to be a problem in the Microsoft products listed at the beginning of this article.


MORE INFORMATION

The Offset property in Visual Basic for Applications for Microsoft Excel returns a Range object that represents a range that is offset from the specified range.

For additional information, please see the following article in the Microsoft Knowledge Base:

Q120198 XL: How to Select Cells/Ranges Using Visual Basic Procedures


REFERENCES

For more information about the Offset property, click the Office Assistant while in the Microsoft Visual Basic editor, type Offset, click Search, and then click to view "Offset Property."

NOTE: If the Assistant is hidden, click the Office Assistant button on the Standard toolbar. If Microsoft Help is not installed on your computer, please see the following article in the Microsoft Knowledge Base:

Q120802 Office: How to Add/Remove a Single Office Program or Component

Additional query words: XL97

Keywords : kbprg kbdta kbdtacode KbVBA xlvbmigrate
Version : WINDOWS:97
Platform : WINDOWS
Issue type : kbbug


Last Reviewed: November 9, 1999
© 2000 Microsoft Corporation. All rights reserved. Terms of Use.