Error Checking in Excel
Thanks Thanks:  0
Likes Likes:  0
Results 1 to 4 of 4

Thread: Two functions in one cell

  1. #1
    New Member
    Join Date
    Apr 2002
    Posts
    10
    Post Thanks / Like
    Mentioned
    0 Post(s)
    Tagged
    0 Thread(s)

    Default

    I am trying to incorporate two functions into one cell. I have the day in one column and time in another column

    Day Time
    14 8:01
    14 8:05
    14 9:06
    15 8:50
    15 8:02
    16 2:00
    16 2:50

    e.g I want to find the number of times day 14 occurs between 8:00 and 9:00. The answer I would be looking for is 2 in this case. I have tried putting in the countif function along with "and" to separate the second function, but it doesn't work. Any suggestions?

  2. #2
    MrExcel MVP Al Chara's Avatar
    Join Date
    Feb 2002
    Location
    Newark, Delaware
    Posts
    1,701
    Post Thanks / Like
    Mentioned
    0 Post(s)
    Tagged
    0 Thread(s)

    Default

    Try the followin:

    =SUMPRODUCT((A2:A8=14)*(B2:B8>=1/3)*(B2:B8<=3/8))
    Best regards,
    Allan Chara
    http://www.mrspreadsheets.com

  3. #3
    MrExcel MVP
    Join Date
    Feb 2002
    Location
    Austin, Texas USA
    Posts
    11,654
    Post Thanks / Like
    Mentioned
    0 Post(s)
    Tagged
    0 Thread(s)

    Default

    {=SUM((A2:A8=14)*(B2:B8>="8:00"+0)*(B2:B8<="9:00"+0))}

    Note: This is an array formula which must be entered using the Control+Shift+Enter key combination. The outermost braces, { }, are not entered by you -- they're supplied by Excel in recognition of a properly entered array formula.

  4. #4
    MrExcel MVP Aladin Akyurek's Avatar
    Join Date
    Feb 2002
    Location
    The Hague, NL
    Posts
    84,049
    Post Thanks / Like
    Mentioned
    38 Post(s)
    Tagged
    8 Thread(s)

    Default

    On 2002-04-10 10:00, Thanh wrote:
    I am trying to incorporate two functions into one cell. I have the day in one column and time in another column

    Day Time
    14 8:01
    14 8:05
    14 9:06
    15 8:50
    15 8:02
    16 2:00
    16 2:50

    e.g I want to find the number of times day 14 occurs between 8:00 and 9:00. The answer I would be looking for is 2 in this case. I have tried putting in the countif function along with "and" to separate the second function, but it doesn't work. Any suggestions?

    =SUMPRODUCT((B2:B8>=C1)*(B2:A8<=C2)*(A2:A3=C3))

    where C1 houses the earlier time, C2 the later time, and C3 the day number.

    You can also try DCOUNT:

    In D1 enter: Time
    In E1 enter: Time
    In F1 enter: Day

    In D2 enter: >=8:00
    In E2 enter: <=9:00
    In F2 enter: 14

    =DCOUNT(A1:B8,1,D1:F2)

    Aladin

Some videos you may like

User Tag List

Like this thread? Share it with others

Like this thread? Share it with others

Posting Permissions

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