• Countif in an array of a cell (Excel 2003)

    Home » Forums » AskWoody support » Productivity software by function » MS Excel and spreadsheet help » Countif in an array of a cell (Excel 2003)

    Author
    Topic
    #457712

    Any way to return the number of count on criteria in a cell from column B

    Users place the type of response in a cell.
    They may select I (Immediate), L (Later), H (HEAT), F (Feedback), M (Meeting).
    I need to count the numbers of each of these I have.
    The problem is that the users are putting multiple selections in one cell, such as I,H,F.
    Their multiple selections are separated by a comma with no additional spacing.
    Do I have any way to count each of the I’s, each of the H’s, and each of the F’s when they do this together
    with those that are single I’s, H’s,F’s which the CountIF function can handle

    TIA

    Viewing 1 reply thread
    Author
    Replies
    • #1148448

      Let’s say you have responses in B1:B1000.
      The number of cells that contain an I (whether as a single response or as part of a multiple response) is given by the following array formula (confirm with Ctrl+Shift+Enter):

      =SUM(--NOT(ISERROR(SEARCH("I",$B$1:$B$1000))))

      If you place the letter I in a cell, let’s say in G1, you can use

      =SUM(--NOT(ISERROR(SEARCH(G1,$B$1:$B$1000))))

      You can place the other letters in G2, G3 etc. and fill the formula down.

      • #1148453

        Thanks Hans

        Would you mind giving a small explanation on the formula, especially on the part
        NOT(ISERROR. Am not too sure what it does in the formula,
        I know that this formula add the number of TRUE return

        TIA

        • #1148502

          SEARCH(“I”,$B$1:$B$1000) searches for the letter “I” in each of the cells B1:B1000 (not case sensitive).
          If “I” occurs, it returns the position of the first occurrance (e.g. 3 if the 3rd letter is “I”). If “I” does not occur, it returns an #VALUE error.

          ISERROR(SEARCH(“I”,$B$1:$B$1000)) returns TRUE for each cell in which “I” is NOT found, FALSE otherwise.

          NOT(ISERROR(SEARCH(“I”,$B$1:$B$1000))) returns FALSE for each cell in which “I” is not found, TRUE otherwise.

          –NOT(ISERROR(SEARCH(“I”,$B$1:$B$1000))) forces FALSE to its numeric equivalent 0 and TRUE to 1.

          =SUM(–NOT(ISERROR(SEARCH(“I”,$B$1:$B$1000)))) as an array formula adds the 0s and 1s, counting each cell in which “I” occurs as 1.

    • #1148605

      Any way to return the number of count on criteria in a cell from column B

      Users place the type of response in a cell.
      They may select I (Immediate), L (Later), H (HEAT), F (Feedback), M (Meeting).
      I need to count the numbers of each of these I have.
      The problem is that the users are putting multiple selections in one cell, such as I,H,F.
      Their multiple selections are separated by a comma with no additional spacing.
      Do I have any way to count each of the I’s, each of the H’s, and each of the F’s when they do this together
      with those that are single I’s, H’s,F’s which the CountIF function can handle

      TIA

      You can also use wildcards with countif:
      =COUNTIF($B$1:$B$1000,”*I*”)
      for example.

    Viewing 1 reply thread
    Reply To: Countif in an array of a cell (Excel 2003)

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

    Your information: