+ Reply to Thread
Results 1 to 5 of 5

Count Problem

  1. #1
    Registered User
    Join Date
    08-15-2005
    Posts
    8

    Count Problem

    Hi

    Can anyone help?

    I have a basic logging sheet, which is recording reports in and out of my department. Column E shows which sub-team they went to ie Transport, Engineering or Construction. Column G is the date out column. I have a separate table with an overview per team.

    The overview table lists the teams down the left, and then working across the next column counts the number of reports for each team - easy enough with a basic =COUNTIF(E5:E250,"Engineering") etc...... However in the next column of my overview I want to count those reports completed per team by counting if there is a date in column G, but against the appropriate team. Any ideas? Probably dead simple - but I can't find how to do it!

    Thanks

    HDV

  2. #2
    Biff
    Guest

    Re: Count Problem

    Hi!

    Try this:

    =SUMPRODUCT(--(Range1="Engineering"),--(ISNUMBER(Range2)))

    Biff

    "HDV" <[email protected]> wrote in message
    news:[email protected]...
    >
    > Hi
    >
    > Can anyone help?
    >
    > I have a basic logging sheet, which is recording reports in and out of
    > my department. Column E shows which sub-team they went to ie
    > Transport, Engineering or Construction. Column G is the date out
    > column. I have a separate table with an overview per team.
    >
    > The overview table lists the teams down the left, and then working
    > across the next column counts the number of reports for each team -
    > easy enough with a basic =COUNTIF(E5:E250,"Engineering") etc......
    > However in the next column of my overview I want to count those reports
    > completed per team by counting if there is a date in column G, but
    > against the appropriate team. Any ideas? Probably dead simple - but I
    > can't find how to do it!
    >
    > Thanks
    >
    > HDV
    >
    >
    > --
    > HDV
    > ------------------------------------------------------------------------
    > HDV's Profile:
    > http://www.excelforum.com/member.php...o&userid=26299
    > View this thread: http://www.excelforum.com/showthread...hreadid=536989
    >




  3. #3
    Registered User
    Join Date
    08-15-2005
    Posts
    8
    It works - how does it work though I'm bamboozled. - thanks Biff.

    HDV

  4. #4
    L. Howard Kittle
    Guest

    Re: Count Problem

    Take a look at this site to help you understand sumproduct.

    http://www.xldynamic.com/source/xld....T.html#classic

    HTH
    Regards,
    Howard

    "HDV" <[email protected]> wrote in message
    news:[email protected]...
    >
    > Hi
    >
    > Can anyone help?
    >
    > I have a basic logging sheet, which is recording reports in and out of
    > my department. Column E shows which sub-team they went to ie
    > Transport, Engineering or Construction. Column G is the date out
    > column. I have a separate table with an overview per team.
    >
    > The overview table lists the teams down the left, and then working
    > across the next column counts the number of reports for each team -
    > easy enough with a basic =COUNTIF(E5:E250,"Engineering") etc......
    > However in the next column of my overview I want to count those reports
    > completed per team by counting if there is a date in column G, but
    > against the appropriate team. Any ideas? Probably dead simple - but I
    > can't find how to do it!
    >
    > Thanks
    >
    > HDV
    >
    >
    > --
    > HDV
    > ------------------------------------------------------------------------
    > HDV's Profile:
    > http://www.excelforum.com/member.php...o&userid=26299
    > View this thread: http://www.excelforum.com/showthread...hreadid=536989
    >




  5. #5
    Biff
    Guest

    Re: Count Problem

    Hi!

    Try this little exercise:

    Create this small table:

    ...........A...................B
    1.......Eng..........4/27/2006
    2.......Const.......3/30/2006
    3.......Eng...........Pending
    4.......Trans........Pending
    5.......Eng...........(empty)

    Now lets break down the formula into its individual parts:

    =SUMPRODUCT(--(A1:A5="Eng"),--(ISNUMBER(B1:B5)))

    Enter this formula in D1 and copy down to D5:

    =--(A1="Eng")

    Enter this formula in E1 and copy down to E5:

    =--ISNUMBER(B1)

    Enter this formula F1 and copy down to F5:

    =D1*E1

    And finally, enter this formula in G1:

    =SUM(F1:F5)

    That's what's happening with this formula:

    =SUMPRODUCT(--(A1:A5="Eng"),--(ISNUMBER(B1:B5)))

    Dates are really just numbers that are formatted to look like dates. So, to
    test if a date is present all you need to do is test the cell to see if it
    contains a number, thus ISNUMBER.

    The "--" double unary is used to convert boolean values: TRUE or FALSE to
    numeric values 1 or 0:

    (A1="Eng") will return either TRUE or FALSE

    --(A1="Eng") will return either 1 or 0

    Biff

    "HDV" <[email protected]> wrote in message
    news:[email protected]...
    >
    > It works - how does it work though I'm bamboozled. - thanks Biff.
    >
    > HDV
    >
    >
    > --
    > HDV
    > ------------------------------------------------------------------------
    > HDV's Profile:
    > http://www.excelforum.com/member.php...o&userid=26299
    > View this thread: http://www.excelforum.com/showthread...hreadid=536989
    >




+ Reply to Thread

Thread Information

Users Browsing this Thread

There are currently 1 users browsing this thread. (0 members and 1 guests)

Bookmarks

Posting Permissions

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

Search Engine Friendly URLs by vBSEO 3.6.0 RC 1