XL2000: How to Count Rows Displayed After Data Has Been Filtered (213330)



The information in this article applies to:

  • Microsoft Excel 2000

This article was previously published under Q213330

SUMMARY

This article contains a sample Microsoft Visual Basic for Applications Sub procedure (macro) that counts the number of rows that remain after you use AutoFilter or Advanced Filter on the Data menu to filter a list.

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 a Microsoft Certified Partner or the Microsoft fee-based consulting line at (800) 936-5200. For more information about Microsoft Certified Partners, please visit the following Microsoft Web site: For more information about the support options that are available and about how to contact Microsoft, visit the following Microsoft Web site: To create and run a macro to count the number of rows remaining after you filter a list, use the steps in the following example:
  1. Start Excel and create the following spreadsheet:
    A1:  Last Name	B1:  First Name
    A2:  Jones	B2:  Gary
    A3:  Jones	B3:  Larry
    A4:  Jones	B4:  Mary
    A5:  Smith	B5:  Gary
    A6:  Smith	B6:  Larry
    A7:  Smith	B7:  Mary
    					
  2. Press ALT+F11 to start the Visual Basic editor.
  3. On the Insert menu, click Module.
  4. In the module sheet, type the following code:
    Sub Count_Filtered_Rows()
        Dim UpperLeftCorner As Range
        ' UpperLeftCorner should be set to the upper-left
        ' corner of the list range:
        Set UpperLeftCorner = Sheets("Sheet1").Range("A1")
        rowcount = -1
        For Each area In _
            UpperLeftCorner.CurrentRegion.SpecialCells(xlVisible).Areas
            rowcount = rowcount + area.Rows.Count
        Next
        MsgBox rowcount
    End Sub
    					
  5. Press ALT+F11 to return to Excel.
  6. Select cells A1:B7.
  7. On the Data menu, point to Filter, and then click AutoFilter.
  8. Click the arrow in the "Last Name" data column.
  9. Click Jones.

    Note that only the three "Jones" names appear.
  10. On the Tools menu, point to Macro, and then click Macros.
  11. In the Macro name list, click Count_Filtered_Rows, and then click Run.

    Note that a message box appears with the number "3" in it.

Modification Type:MinorLast Reviewed:10/11/2006
Keywords:kbdtacode kbhowto kbProgramming KB213330