Results 1 to 5 of 5
  1. #1
    3 Star Lounger
    Join Date
    Nov 2005
    Location
    Asia Pacific, Bangkok Metropolis
    Posts
    378
    Thanks
    0
    Thanked 0 Times in 0 Posts

    Countif in an array of a cell (Excel 2003)

    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
    Hope this is helpful

    francis, <img src=/S/cheers.gif border=0 alt=cheers width=30 height=16>

    My Reading

    Pivot Table 101
    Pivot Table
    Array

  2. #2
    Plutonium Lounger
    Join Date
    Mar 2002
    Posts
    84,353
    Thanks
    0
    Thanked 29 Times in 29 Posts

    Re: Countif in an array of a cell (Excel 2003)

    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):
    <code>
    =SUM(--NOT(ISERROR(SEARCH("I",$B$1:$B$1000))))
    </code>
    If you place the letter I in a cell, let's say in G1, you can use
    <code>
    =SUM(--NOT(ISERROR(SEARCH(G1,$B$1:$B$1000))))
    </code>
    You can place the other letters in G2, G3 etc. and fill the formula down.

  3. #3
    3 Star Lounger
    Join Date
    Nov 2005
    Location
    Asia Pacific, Bangkok Metropolis
    Posts
    378
    Thanks
    0
    Thanked 0 Times in 0 Posts

    Re: Countif in an array of a cell (Excel 2003)

    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
    Hope this is helpful

    francis, <img src=/S/cheers.gif border=0 alt=cheers width=30 height=16>

    My Reading

    Pivot Table 101
    Pivot Table
    Array

  4. #4
    Plutonium Lounger
    Join Date
    Mar 2002
    Posts
    84,353
    Thanks
    0
    Thanked 29 Times in 29 Posts

    Re: Countif in an array of a cell (Excel 2003)

    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.

  5. #5
    WS Lounge VIP rory's Avatar
    Join Date
    Dec 2000
    Location
    Burwash, East Sussex, United Kingdom
    Posts
    6,280
    Thanks
    3
    Thanked 191 Times in 177 Posts
    [quote name='franciz' post='760477' date='Feb 22 2009, 01:30 PM']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[/quote]

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

    Microsoft MVP - Excel

Posting Permissions

  • You may not post new threads
  • You may not post replies
  • You may not post attachments
  • You may not edit your posts
  •