XL: How to Sum a Range of Cells Based on a Number Format

Last reviewed: February 3, 1998
Article ID: Q164317
The information in this article applies to:
  • Microsoft Excel 98 Macintosh Edition
  • Microsoft Excel 97 for Windows
  • Microsoft Excel for Windows 95, versions 7.0, 7.0a
  • 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

SUMMARY

This article includes a sample Microsoft Visual Basic for Applications custom function that sums the values in a range of cells that are formatted with a specific custom number format.

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

The following example creates a user-defined function that sums values based on a custom number format.

Preparing Sample Data

  1. Create a new workbook and type the following data:

          A1: 100
          A2: 5
          A3: 100
          A4: 5
          A5: 100
    

  2. Select cells A1, A3, and A5. To do this, press and hold down CTRL, and then click cells A1, A3, and A5.

  3. On the Format menu, click Cells. Click the Number tab.

  4. In the Category list, click Custom. In the Type box, type "F"0, and then click OK.

NOTE: You can use different custom number formats with this example.

Creating the Function in Microsoft Excel 97 and 98

  1. Press ALT+F11 to start the Visual Basic Editor.

  2. On the Insert menu, click Module.

  3. In the module sheet, type the following code:

          Function SumFormat(CellRange)
    

             ' Loop through each cell in the range that is passed to this
             ' function.
             For Each Item In CellRange
    
                ' Check to see if the cell is formatted as "F"0.
                ' The additional quotation marks are necessary to look for
                ' actual quotation marks in the format string.
                If Item.NumberFormat = """F""0" Then
    
                   ' Add the cell value to the variable total.
                   total = total + Item.Value
    
                End If
    
             Next Item
    
             ' Set the results of total equal to the function name.
             SumFormat = total
    
          End Function
    
    

  4. On the File menu, click "Close and Return to Microsoft Excel."

  5. Select cell A7.

  6. Type "=SumFormat(A1:A5)" (without the quotation marks), and then press ENTER.

    Cell A7 contains the value 300 because cells A2 and A4 are not formatted with the custom number format of "F"0.

Creating the Function in Microsoft Excel 5.0 and 7.0

  1. On the Insert menu, point to Macro, and then click Module.

  2. In the module sheet, type the following code:

          Function SumFormat(CellRange)
    

             ' Loop through each cell in the range that is passed to this
             ' function.
             For Each Item In CellRange
    
                ' Check to see if the cell is formatted as "F"0.
                ' The additional quotation marks are necessary to look for
                ' actual quotation marks in the format string.
                If Item.NumberFormat = """F""0" Then
    
                   ' Add the cell value to the variable total.
                   total = total + Item.Value
    
                End If
    
             Next Item
    
             ' Set the results of total equal to the function name.
             SumFormat = total
    
          End Function
    
    

  3. Click Sheet1.

  4. Select cell A7.

  5. Type "=SumFormat(A1:A5)" (without the quotation marks), and then press ENTER.

    Cell A7 contains the value 300 because cells A2 and A4 are not formatted with the custom number format of "F"0.

REFERENCES

For more information about number formats, click the Index tab in Microsoft Excel Help, type the following text

   number formats, in cells

and then double-click the selected text to go to the "Create a custom number format" topic.


Additional query words:
Keywords : kbcode kbprg
Version : WINDOWS:5.0,5.0c,7.0,97; MACINTOSH:5.0a,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.