Microsoft provides programming examples for illustration only, without warranty either expressed or implied. This includes, but is not limited to, the implied warranties of merchantability or fitness for a particular purpose. This article assumes that you are familiar with the programming language that is being demonstrated and with the tools that are used to create and to 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 requirements.
The following example creates a user-defined function that sums values
based on a custom number format.
Preparing sample data
- Create a new workbook and type the following data:
A1: 100
A2: 5
A3: 100
A4: 5
A5: 100
- Select cells A1, A3, and A5. To do this, press and hold down CTRL
(or COMMAND on a Macintosh), and then click cells A1, A3, and A5.
- On the Format menu, click Cells. Click the Number tab.
- In the Category list, click Custom. In the Type box, type F0, and then
click OK.
Note You can use different custom number formats with this example.
Creating the function in the versions of Excel that are listed in the "Applies To" section
- Press ALT+F11 to start the Visual Basic Editor.
- On the Insert menu, click Module.
- 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
- Use one of the following methods:
- In Excel X for Mac and later versions, click Close and Return to Microsoft Excel on the Excel menu.
- In all other versions of Excel, click Close and Return to Microsoft Excel on the File menu.
- Select cell A7.
- Type =SumFormat(A1:A5), 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
- On the Insert menu, point to Macro, and then click Module.
- 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
- Click Sheet1.
- Select cell A7.
- Type =SumFormat(A1:A5), 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.