Sum if cells contain an asterisk

=SUMIF(range,"*~**",sum_range)
To sum if cells contain an asterisk, you can use the SUMIF function with criteria that uses the tilde (~). In the example shown, cell G6 contains this formula:
=SUMIF(C5:C11,"*~**",D5:D11)
This formula sums the amounts in column D when a value in column C contains "*".
The SUMIF function supports wildcards. An asterisk (*) means "one or more characters", while a question mark (?) means "any one character". These wildcards allow you to create criteria such as "begins with", "ends with", "contains 3 characters" and so on.
Because asterisks and question marks are themselves wildcards, if you want to search for these characters specifically, you'll need to escape them with a tilde (~). The tilde causes Excel to handle the next character literally.
In this case we are using "~*" to match a literal asterisk, but this is surrounded by asterisks on either side, in order to match an asterisk anywhere in the cell. If you just want to match an asterisk at the end of a cell, use: "*~*" for the criteria.
Alternative with SUMIFS
You can also use the SUMIFS function. SUMIFS can handle multiple criteria, and the order of the arguments is different from SUMIF. With SUMIFS, the sum range always comes first in the argument list, followed by range/criteria pairs:
=SUMIFS(D5:D11,C5:C11,"*~**")
Download 200+ Excel Shortcuts
Get over 200 Excel shortcuts for Windows and Mac in one handy PDF.