XL: How to Check Number of Records Returned in an AutoFilter

Last reviewed: February 3, 1998
Article ID: Q152215
The information in this article applies to:
  • Microsoft Excel for Windows, versions 5.0, 5.0c
  • Microsoft Excel for the Macintosh, versions 5.0, 5.0a
  • Microsoft Excel for Windows NT, version 5.0
  • Microsoft Excel for Windows 95, versions 7.0, 7.0a
  • Microsoft Excel 97 for Windows
  • Microsoft Excel 98 Macintosh Edition

SUMMARY

This article contains a sample Microsoft Visual Basic for Applications macro (Sub procedure) that determines how many records were returned in an auto-filtered list. You can also use the Subtotal function to achieve a similar result. Both methods are detailed in the "More Information" section of this article.

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 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 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/default.asp

Using a Visual Basic Macro

  1. Insert a module sheet and 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
    
    

  2. 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
    
    

  3. Run the macro.

    Microsoft Excel 97 and Microsoft Excel 98 -----------------------------------------

    On the Tools menu, point to Macro, and then click Macros. In the Macro box, select Filter_Return, and then click Run.

    Microsoft Excel versions 5.0 and 7.0 ------------------------------------

    On the Tools Menu, click Macro. In the Macro box, select 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.

Using the Subtotal Function

  1. Use the same sample data from Step 2, above. If the AutoFilter is currently on, point to Filter on the Data menu, and then click AutoFilter.

  2. In cell C8, type the following formula:

          =SUBTOTAL(3,C2:C6)
    

    NOTE: The first argument for the Subtotal function is the function used to calculate the subtotal. The argument in this example uses the Count function (3) to calculate the subtotal.

  3. Select cell A1, point to Filter on the Data menu, and then click AutoFilter.

    This turns on the AutoFilter, and you get a drop-down box for each of the three fields in this example.

  4. Click the drop-down box in the Animal field, and then click Cat in the drop-down list.

    The AutoFilter filters all the records with Cat in the Animal field, and in this example, the result of the Subtotal function in cell C8 is 2.


Additional query words: 7.00 5.00 copy paste visual basic sub total XL98
XL97 XL7 XL5
Keywords : kbcode kbprg PgmHowto
Version : WINDOWS:5.0,5.0c,7.0,7.0a,97; MACINTOSH:5.0,98
Platform : MACINTOSH WINDOWS
Issue type : kbhowto


THE INFORMATION PROVIDED IN THE MICROSOFT KNOWLEDGE BASE IS PROVIDED "AS IS" WITHOUT WARRANTY OF ANY KIND. MICROSOFT DISCLAIMS ALL WARRANTIES, EITHER EXPRESS OR IMPLIED, INCLUDING THE WARRANTIES OF MERCHANTABILITY AND FITNESS FOR A PARTICULAR PURPOSE. IN NO EVENT SHALL MICROSOFT CORPORATION OR ITS SUPPLIERS BE LIABLE FOR ANY DAMAGES WHATSOEVER INCLUDING DIRECT, INDIRECT, INCIDENTAL, CONSEQUENTIAL, LOSS OF BUSINESS PROFITS OR SPECIAL DAMAGES, EVEN IF MICROSOFT CORPORATION OR ITS SUPPLIERS HAVE BEEN ADVISED OF THE POSSIBILITY OF SUCH DAMAGES. SOME STATES DO NOT ALLOW THE EXCLUSION OR LIMITATION OF LIABILITY FOR CONSEQUENTIAL OR INCIDENTAL DAMAGES SO THE FOREGOING LIMITATION MAY NOT APPLY.

Last reviewed: February 3, 1998
© 1998 Microsoft Corporation. All rights reserved. Terms of Use.