XL: Range Command in Macro Selects Cells from Entire Range

ID: Q133139

The information in this article applies to:

SYMPTOMS

When you use Microsoft Visual Basic for Applications to work with a filtered list, range commands will select cells from the entire current range, not just from the visible cells as you might expect.

MORE INFORMATION

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/refguide/

The following are two examples of Visual Basic code. One example selects all the visible cells in a filtered list and treats them as a selection, while the other selects specific visible cells for the purpose of cell manipulation.

Select All the Visible Cells in a Filtered List

Note that while this method is acceptable for modifying or copying all the cells in a selection, it does not provide a way to address specific cells in a filtered list.

1. To set up a filtered list on a worksheet, follow these steps:

    a. In a new worksheet, enter the following values:

         A1: Value A  B1: Value B  C1: Value C
         A2: A-2      B2: B-2      C2: C-2
         A3: A-3      B3: B-3      C3: C-3
         A4: A-4      B4: B-4      C4: C-4
         A5: A-5      B5: B-5      C5: C-5
         A6: A-6      B6: B-6      C6: C-6
         A7: A-7      B7: B-7      C7: C-7
         A8: A-8      B8: B-8      C8: C-8
         A9: A-9      B9: B-9      C9: C-9
        A10: A-10    B10: B-10    C10: C-10

    b. While holding down the CTRL key, use the mouse to select rows 3, 4,
       6, 7, 8, and 10.

    c. On the Format menu, click Row, and then click Hide.

   At this point, only the header row and rows 2, 5, and 9 should be
   visible.

2. Enter the following Visual Basic for Applications code on a module
   sheet.

   ' The following Visual Basic for Applications code provides the ability
   ' to select all of the visible cells in the current region based on a
   ' single cell (similar to the way sort works); it allows you to copy
   ' only the visible cells to another worksheet.

   Sub Select_All_Visible_Cells()
      'Select all cells that have a "visible" property.
      Range("A1").CurrentRegion.SpecialCells(xlVisible).Select
      'Copy the visible cells to worksheet named "Sheet2".
      Selection.Copy Worksheets("Sheet2").Range("A1")
   End Sub

Select Specific Cells in a Filtered List

The first step in selecting a specific cell in a filtered list is to determine which rows are visible and which rows are hidden. You can then select specific cells in the visible row.

1. To create a list, follow step 1 from the "Select All the Visible Cells

   in a Filtered List" section earlier.

2. Enter the following Visual Basic code on a module sheet.

    Sub Select_Specific_Visible_Cells()
      '   Area is set as an object that defines the Current Region.
      '   Current Region contains all the cells starting at the cell
      '   defined in the Range Method and bounded by blank rows and blank
      '   columns (or the edges of the worksheet).
      Set area = Range("A1").CurrentRegion
      '   LastColumn is the column number for the last column in the
      '   Current Region.
      lastcolumn = area.Columns.Count
      '   EndRow is set as an object that contains all the cells in the
      '   last row (the last record) in Current Region.
      Set endrow = area.Offset(area.Rows.Count - 1).Resize(1, lastcolumn)
      '   SearchRow is set as an object that contains the first row in the
      '   current region.
      Set searchrow = area.Resize(1, lastcolumn)
      '   The outside "Do Until" loop allows us to look at each row, one
      '   row at a time until we reach the end of the Current Region.
      Do Until searchrow.Row >= endrow.Row
      '   The inside "Do" loop locates the next visible.(not hidden) row.
         Do
      '   Verify we didn't select past the end of the Current Region.
            If searchrow.Row < endrow.Row Then
      '   If OK then select the next row to be checked.
               Set searchrow = searchrow.Offset(1)
            Else
      '   If the selection goes past the end of Current Region, exit the
      '   sub.
               Exit Sub
            End If
      '   Continue to look until a row is found that's not hidden.
         Loop Until searchrow.EntireRow.Hidden = False
      '   Select the visible row.
      searchrow.Select
      '   The "For Each" loop allows you to look at, copy, modify, and so
      '   on, each cell in the visible row. "MsgBox" then displays each
      '   cell's value.
         For Each Cell In Selection
            MsgBox Cell.Value
         Next
      '   After we process a visible row, loop back and look for another.
      Loop
   End Sub

In this example, the message box displays the contents of each of the three cells in each of the visible rows 2, 5, and 9. You could replace "For Each

Cell In Selection" with the Range Cells method to select specific cells from the selected visible rows.

REFERENCES

"Visual Basic User's Guide," version 5.0, Chapter 5, "The Range Object," pages 82-84

Additional query words: 5.00 5.00c 7.00 8.00 97 XL97

Keywords          : kbprg kbdta KbVBA 
Version           : WINDOWS:5.0,5.0c,7.0,97
Platform          : WINDOWS
Issue type        : kbhowto

Last Reviewed: May 17, 1999