XL2000: Macro to Count the Number of Records Returned in an AutoFiltered List (213275)



The information in this article applies to:

  • Microsoft Excel 2000

This article was previously published under Q213275

SUMMARY

This article contains a sample Microsoft Visual Basic for Applications macro (Sub procedure) that determines how many records were returned in a list that has AutoFilter turned on.

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 determine how many records are returned in a list with the AutoFilter feature turned on, follow these steps:
  1. Open a new workbook in Microsoft Excel, and then start the Visual Basic Editor (press ALT+F11).
  2. On the Insert menu, click Module.
  3. In the module sheet, type the following code:
    Sub Filter_Return()
        Sheets("sheet1").Select
        Range("a1").Select
        Selection.CurrentRegion.Select
        row_count = Selection.Rows.Count - 1     ' Count the rows and
                                                 ' subtract the header.
    
        ' The following three lines run an AutoFilter using "Cat" as the
        ' criteria for the first column and greater than 0 as the
        ' criteria for the second column.
        Selection.AutoFilter
        Selection.AutoFilter Field:=1, Criteria1:="Cat"
        Selection.AutoFilter Field:=2, Criteria1:=">0"
        matched_criteria = 0                         ' Set variable to
                                                     ' zero.
        check_row = 0                                ' Set variable to
                                                     ' zero.
        While Not IsEmpty(ActiveCell)            ' Check to see if row
                                                 ' height is zero.
            ActiveCell.Offset(1, 0).Select
            If ActiveCell.RowHeight = 0 Then
                check_row = check_row + 1
            Else
                matched_criteria = matched_criteria + 1
            End If
        Wend
    
        If row_count = check_row Then            ' If these are equal,
                                                 ' nothing was returned.
            MsgBox "no matching data"
        Else
            MsgBox matched_criteria - 1          ' Display the number
                                                 ' of records returned.
        End If
    
    End Sub
    					
  4. Switch to Excel (press ALT+F11), and type the following information in a worksheet:
           A1:  Animal     B1:  In Stock         C1:  Price
           A2:  Dog        B2:  1                C2:  $1.00
           A3:  Cat        B3:  2                C3:  $2.00
           A4:  Dog        B4:  3                C4:  $3.00
           A5:  Cat        B5:  4                C5:  $4.00
           A6:  Bird       B6:  5                C6:  $5.00
     
    					
  5. On the Tools menu, point to Macro, and then click Macros. In the Macro box, click Filter_Return, and then click Run.
The macro displays a message box that states the number of records returned or, if no data is returned, that there is "no matching data." In the example given, the message box returns the number 2.

REFERENCES

You can also use the SUBTOTAL function to achieve a similar result. For additional information about how to use the SUBTOTAL function to count the number of records returned in an AutoFiltered list, click the article number below to view the article in the Microsoft Knowledge Base:

244789 XL2000: How to Use the SUBTOTAL Function with AutoFilter


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