• How to Count number of items in a sum formula (97)

    Home » Forums » AskWoody support » Productivity software by function » MS Excel and spreadsheet help » How to Count number of items in a sum formula (97)

    Author
    Topic
    #401267

    Cell A1 has the formula =12+0+20+49+2+15+55 cell A1 shows the sum and that is as it needs to be, then I would like Cell A2 to show a count of how many items/individual numbers there are in the formula, ie 7. And show if a change is made in cell A1.

    Viewing 3 reply threads
    Author
    Replies
    • #789118

      If you have Laurent Longre’s excellent Morefunc, you can use the FormulaText function from that add-in. Otherwise, create this user-defined function in a standard module (in Personal.xls if you like):

      Function FormulaText(aCell As Range) As String
      FormulaText = aCell.Cells(1).Formula
      End Function

      The following formula, entered as an array formula (i.e. confirm with Ctrl+Shift+Enter) will count the number of “+” characters in the formula and add 1:
      With MoreFunc:
      =SUM(IF(MID(FORMULATEXT(A1,,,TRUE),ROW(1:1024),1)=”+”,1,0))+1
      With custom function:
      =SUM(IF(MID(FORMULATEXT(A1),ROW(1:1024),1)=”+”,1,0))+1

      This is not very flexible – it doesn’t take other operators into account.

      • #789240

        Thank you gentlemen. You hit it right on. I knew someone here would have an answer. But now I remember why I quit coming in here. I do not understand two words out of ten of what you posted. I have no idea how to create a user-defined function in a standard module. Is that like a macro? Or what an option explicit is or how or where to create that.

        Fortunately I was able to decipher Laurent Longre’s download (even tho I do not speak French). And type in the string. Both provided by Hans worked after the doing the download.

        So again thanks for the link. This is a great board even if it is too advanced for this redhead.

        • #789276

          Hi BookLady,

          I’m glad you made it work. It is difficult to estimate how much detail a reply should contain, but you can always ask for more details or for an explanation. The Lounge tries to help users with all levels of experience.

          You probably don’t need it any more, maybe don’t even want to know it, but here is a bit of background on custom functions. They are a bit like macros indeed, but instead of “running” them, you can use them in formulas, just like built-in functons such as SUM or COUNT.

          To create a custom function:

          • Select Tools | Macro | Visual Basic Editor… (or type Alt+F11) to activate the Visual Basic Editor.
          • Select Insert | Module to create a new module. (This is called a “standard” module; there is also another type called a class module, but you don’t need to bother with that now.)
          • Type the code, or copy it from a post and paste it. In my example, it was

            Function FormulaText(aCell As Range) As String
            FormulaText = aCell.Cells(1).Formula
            End Function

            This means: we define a function named FormulaText. You have to feed it one argument of type Range, that is, a cell reference. The result will be a string (a text). The function takes the first cell in the range passed to it, and returns the formula of that cell.

          • The line Option Explicit in Steve’s code is usually not typed in by yourself. It is inserted automatically into every new module, provided that you have ticked “Require Variable Declaration” in the Tools | Options… dialog. In Visual Basic Code, you can use variables to store information temporarily; Option Explicit means that you *must* declare (announce) every variable before using it in a statement such as “Dim intPosition As Integer”.
            [/list]
          • #789602

            Thank you Hans. That is great and not too complicated. Having run in panic from all those modules in Visual Basic when trying to edit Macros, it is nice that Longre allready did that part for people like me But thanks for the further instructions it is always good to learn something new. Am going to see how badly it is possible to screw up Xl by removing Longre’s and trying to use yours.

            This is a great board as I said in my previous post. Just way too tech for me. But the other boards couldn’t come up with an answer. So I asked at my “Ace in the hole” backup board and sure enough not one but several answers.

            • #789620

              Thanks for letting us know what had happened to you. Usually when someone asks questions as clearly and concisely as you do they have a better than average technical understanding. As/when you come here again, don’t be at all shy about asking for step by step explanations.

            • #789621

              Thanks for letting us know what had happened to you. Usually when someone asks questions as clearly and concisely as you do they have a better than average technical understanding. As/when you come here again, don’t be at all shy about asking for step by step explanations.

          • #789603

            Thank you Hans. That is great and not too complicated. Having run in panic from all those modules in Visual Basic when trying to edit Macros, it is nice that Longre allready did that part for people like me But thanks for the further instructions it is always good to learn something new. Am going to see how badly it is possible to screw up Xl by removing Longre’s and trying to use yours.

            This is a great board as I said in my previous post. Just way too tech for me. But the other boards couldn’t come up with an answer. So I asked at my “Ace in the hole” backup board and sure enough not one but several answers.

        • #789277

          Hi BookLady,

          I’m glad you made it work. It is difficult to estimate how much detail a reply should contain, but you can always ask for more details or for an explanation. The Lounge tries to help users with all levels of experience.

          You probably don’t need it any more, maybe don’t even want to know it, but here is a bit of background on custom functions. They are a bit like macros indeed, but instead of “running” them, you can use them in formulas, just like built-in functons such as SUM or COUNT.

          To create a custom function:

          • Select Tools | Macro | Visual Basic Editor… (or type Alt+F11) to activate the Visual Basic Editor.
          • Select Insert | Module to create a new module. (This is called a “standard” module; there is also another type called a class module, but you don’t need to bother with that now.)
          • Type the code, or copy it from a post and paste it. In my example, it was

            Function FormulaText(aCell As Range) As String
            FormulaText = aCell.Cells(1).Formula
            End Function

            This means: we define a function named FormulaText. You have to feed it one argument of type Range, that is, a cell reference. The result will be a string (a text). The function takes the first cell in the range passed to it, and returns the formula of that cell.

          • The line Option Explicit in Steve’s code is usually not typed in by yourself. It is inserted automatically into every new module, provided that you have ticked “Require Variable Declaration” in the Tools | Options… dialog. In Visual Basic Code, you can use variables to store information temporarily; Option Explicit means that you *must* declare (announce) every variable before using it in a statement such as “Dim intPosition As Integer”.
            [/list]
      • #789241

        Thank you gentlemen. You hit it right on. I knew someone here would have an answer. But now I remember why I quit coming in here. I do not understand two words out of ten of what you posted. I have no idea how to create a user-defined function in a standard module. Is that like a macro? Or what an option explicit is or how or where to create that.

        Fortunately I was able to decipher Laurent Longre’s download (even tho I do not speak French). And type in the string. Both provided by Hans worked after the doing the download.

        So again thanks for the link. This is a great board even if it is too advanced for this redhead.

    • #789119

      If you have Laurent Longre’s excellent Morefunc, you can use the FormulaText function from that add-in. Otherwise, create this user-defined function in a standard module (in Personal.xls if you like):

      Function FormulaText(aCell As Range) As String
      FormulaText = aCell.Cells(1).Formula
      End Function

      The following formula, entered as an array formula (i.e. confirm with Ctrl+Shift+Enter) will count the number of “+” characters in the formula and add 1:
      With MoreFunc:
      =SUM(IF(MID(FORMULATEXT(A1,,,TRUE),ROW(1:1024),1)=”+”,1,0))+1
      With custom function:
      =SUM(IF(MID(FORMULATEXT(A1),ROW(1:1024),1)=”+”,1,0))+1

      This is not very flexible – it doesn’t take other operators into account.

    • #789137

      In addition to Hans’s suggestion you could use this function. This only takes the arithmetic operators into account +, -, *, / but it must be simple. IUf the formula is more complicated it could give weird results

      Steve

      Option Explicit
      Function CountItems(rCell As Range) As Integer
          Dim sFormula As String
          Dim sSigns As String
          Dim sClean As String
          Dim x As Integer
          Dim aWF As WorksheetFunction
          
          sSigns = "+-/*"
          Set aWF = Application.WorksheetFunction
          sFormula = rCell.Cells(1, 1).Formula
          sClean = sFormula
          For x = 1 To Len(sSigns)
              sClean = aWF.Substitute(sClean, Mid(sSigns, x, 1), "")
          Next
          CountItems = Len(sFormula) - Len(sClean) + 1
          Set aWF = Nothing
      End Function
    • #789138

      In addition to Hans’s suggestion you could use this function. This only takes the arithmetic operators into account +, -, *, / but it must be simple. IUf the formula is more complicated it could give weird results

      Steve

      Option Explicit
      Function CountItems(rCell As Range) As Integer
          Dim sFormula As String
          Dim sSigns As String
          Dim sClean As String
          Dim x As Integer
          Dim aWF As WorksheetFunction
          
          sSigns = "+-/*"
          Set aWF = Application.WorksheetFunction
          sFormula = rCell.Cells(1, 1).Formula
          sClean = sFormula
          For x = 1 To Len(sSigns)
              sClean = aWF.Substitute(sClean, Mid(sSigns, x, 1), "")
          Next
          CountItems = Len(sFormula) - Len(sClean) + 1
          Set aWF = Nothing
      End Function
    Viewing 3 reply threads
    Reply To: How to Count number of items in a sum formula (97)

    You can use BBCodes to format your content.
    Your account can't use all available BBCodes, they will be stripped before saving.

    Your information: