Please Note: This article is written for users of the following Microsoft Excel versions: 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365. If you are using an earlier version (Excel 2003 or earlier), this tip may not work for you. For a version of this tip written specifically for earlier versions of Excel, click here: Number of Terms in a Formula.
Written by Allen Wyatt (last updated August 6, 2021)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365
Pradeep has a need to figure out the number of terms in any given formula. For instance, in the formula =5+80*3/6 there are four terms. He would like a formula he can use to tell him the number of terms (4) in the formula.
There is no built-in function you can use in Excel to garner this information. Thus, the cleanest approach would be to create your own function, such as the following:
Function TermsInFormula(TheCell As Range) Dim sFormula As String Dim vOps As Variant Dim iCount As Integer Dim J As Integer Dim AWF As WorksheetFunction Application.Volatile vOps = Array("+", "-", "*", "/", "^") Set AWF = Application.WorksheetFunction sFormula = TheCell.Formula iCount = 1 For J = LBound(vOps) To UBound(vOps) iCount = iCount + Len(sFormula) _ - Len(AWF.Substitute(sFormula, vOps(J), "")) Next TermsInFormula = iCount Set AWF = Nothing End Function
The function checks the formula in the referenced cell to see how many of the five mathematical operators it contains. The number of terms in the formula is generally one more than the number of operators, since each term is separated by an operator.
In order to use the function, you would enter the following formula into a cell, assuming that you want to know how many terms are in the formula in cell A1:
=TermsInFormula(A1)
The function will work on formulas, numbers, and text that looks like a formula. It will not, however, consider the "/" in dates as an operator since the display of the date is not part of the Formula property that the function examines. (The display of dates is part of the Text or Value property, not the Formula property.)
Earlier I stated that the number of terms in a formula is generally one more than the number of operators. The operative word here is "generally," as not all formulas are that simple. You'll want to make sure that you visually examine the types of formulas with which you are working and make sure that you are seeing the results you expect.
Note:
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (9458) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365. You can find a version of this tip for the older menu interface of Excel here: Number of Terms in a Formula.
Save Time and Supercharge Excel! Automate virtually any routine task and save yourself hours, days, maybe even weeks. Then, learn how to make Excel do things you thought were simply impossible! Mastering advanced Excel macros has never been easier. Check out Excel 2010 VBA and Macros today!
Insert or delete a column, and Excel automatically updates references within formulas that are affected by the change. If ...
Discover MoreTwo rather common trigonometric functions are secants and cosecants. Excel doesn't provide functions to calculate these, ...
Discover MoreNeed to sum a series of cells that fits some regular pattern? Here are several ways that you can get the summation that ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
2021-08-07 12:08:15
J. Woolley
You can get some interesting information about a formula from this web site: https://www.formulaboost.com/parse
You can also use the FormulaParser macro in My Excel Toolbox, which simply passes the ActiveCell's formula to that site.
See https://sites.google.com/view/MyExcelToolbox/
2021-08-06 16:42:34
David J Bonin
Hmmm...
Would you consider the % sign as an operator?
2021-08-06 15:40:47
Rick Rothstein
Here is another way to write your TermsInFormula function...
Function TermsInFormula(TheCell As Range)
Dim Frmla As String, V As Variant
Frmla = Replace(TheCell.Formula, " ", "")
For Each V In Split("+ - * / ^")
Frmla = Replace(Frmla, V, " ")
Next
TermsInFormula = 1 + UBound(Split(Application.Trim(Frmla)))
End Function
2021-08-06 07:49:28
Billy Thomas
The task can be accomplished with 2 formulas.
1. A simple expression such as "=2+3+4 " can be converted to text using the FORMULATEXT function.
2. With the FORMULATEXT function in Cell A1 for example, use LEN(A1)-LEN(SUBSTITUTE(A1,"+","")).
The result will be 2, the number of +'s in the formula and therefore the number of terms Continue to add "-LEN(SUBSTITUTE's" for other operators. The "=" can generally be ignored.
2014-11-23 11:41:58
John Morriss
According to the definitions of algebra, a term is a collection of factors, multiplied or divided, and separated from other terms by addition or subtraction. The example expression has two terms, the first with one numerical factor, the second with three numerical factors.
2014-11-23 07:46:56
In the first formula you have forgotten to replace an A1 for an A4 in the + substitute block. Same in the second one, there is an A5 instead of A8. That's why the result doesn't work.
You misunderstand the formula. X doesn't represent the number of factors, it's the number of TYPES of factors you are looking for. If you are looking for "+", "-", "*", "/", no matter the number, use 4. If you add to the search list "^", use 5. It will work if each factor is used 1, 0 or 100 times in the formula.
See following example where first I only look for the "+" operator, then I look for everything else. The result is correct and independent of X.
http://i.imgur.com/rlt99d2.png
2014-11-22 05:50:50
Michael (Micky) Avidan
@balthamossa2b,
Sorry, but I find it hard to follow you.
Please take, a good, look at the linked picture.
I don't think I can make myself much clearer than that.
http://i61.tinypic.com/j90zl4.png
Michael (Micky) Avidan
“Microsoft® Answers" - Wiki author & Forums Moderator
“Microsoft®” MVP – Excel (2009-2015)
ISRAEL
2014-11-21 05:43:05
@Micky
For your example, write the formula whose terms you want to count in A1 with a leading apostrophe.
The formula to place in say, B1, is:
=LEN(A1)*4 + 1 - LEN(SUBSTITUTE(A1,"+",""))-LEN(SUBSTITUTE(A1,"*",""))-
LEN(SUBSTITUTE(A1,"/",""))-
LEN(SUBSTITUTE(A1,"^",""))
The result is 6. It will also give the right result by replacing the 4 by 5 and adding another SUBSITUTE term for an additional operator not present in the formula (for example, - ):
=LEN(A1)*5 + 1 - LEN(SUBSTITUTE(A1,"+",""))-LEN(SUBSTITUTE(A1,"*",""))-
LEN(SUBSTITUTE(A1,"/",""))-
LEN(SUBSTITUTE(A1,"^",""))-
LEN(SUBSTITUTE(A1,"-",""))
2014-11-20 05:54:49
Michael (Micky) Avidan
@balthamossa2b,
To the best of my knowledge, the task, in this tip, was to COUNT(!) the number of terms in any given formula.
For instance, in the formula: =5+80*3/6^3+213
the answer is : 6
Can you, please, demonstrate how your, suggested, formula RETURNS the figure: 6 (with or without adding an apostrophe) ?
Michael (Micky) Avidan
“Microsoft® Answers" - Wiki author & Forums Moderator
“Microsoft®” MVP – Excel (2009-2015)
ISRAEL
2014-11-19 10:05:10
I find that defining AWF is unnecessarily convoluted when you can just write it. It feels weird having to set AWF as Worksheet Function when it's defined as such, but I haven't ever used it so I don't know how it works.
If you don't want to use a Worksheet Function you can always use native VBA stuff: INSTR to find the character and use the result as the starting position for the next INSTR. Loop for each character.
Another solution: Application.Match. Much like Substitute it accepts a matrix as searching parameter.
Yet another solution, without need of VBA (props to http://www.ozgrid.com/forum/showthread.php?t=45651 for inspiration):
=LEN(A1)*X + 1 -LEN(SUBSTITUTE(A1,"+","")) -LEN(SUBSTITUTE(A1,"-",""))...
Where X is the number of operators you look for (in this case 5). You just need to put an apostrophe manually before the formula to convert it to text (or use VBA... which kind of defeats the purpose of using a macroless formula).
Got a version of Excel that uses the ribbon interface (Excel 2007 or later)? This site is for you! If you use an earlier version of Excel, visit our ExcelTips site focusing on the menu interface.
FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
Copyright © 2024 Sharon Parq Associates, Inc.
Comments