+ Reply to Thread
Results 1 to 5 of 5

Replace Countifs (Excel 2007) with Sumproduct (Excel 2003)

  1. #1
    Registered User
    Join Date
    01-16-2012
    Location
    Orkney
    MS-Off Ver
    Excel 2007
    Posts
    3

    Replace Countifs (Excel 2007) with Sumproduct (Excel 2003)

    Hi my first time here but I have used this site for lots of help in the past. I normally use Excel 2007 and I have a spreadsheet for use by several other agencies who only have 2003. This means my countifs are not applicable. I have looked at sumproducts and understand the concept. What I need help with is a formula for the following:
    Column A are date formats (to record meeting dates), Column B is a drop down list of outcomes (Yes, No, No reply). I need to record the number of times each month that yes, no and no reply where recorded. It is the greater than, less than part of the formula that I cannot get. i.e. how many times from 01/01/12 to 31/01/12 was "yes" recorded. Am I right in saying I cannot use sumproduct because I am asking for 2 conditions from the same array i.e. date? Thanks for any help.
    Terry
    The formula I was using was
    =COUNTIFS($a$1:$a$200">=01/01/2012",$a$1:$a$200,"<=31/1/2012",$b$10:$b$200,"YES")

    Thanks for any help given. PS I originally posted this under a resolved thread - apologies
    Last edited by TerryE; 02-06-2012 at 11:40 AM.

  2. #2
    Forum Expert NBVC's Avatar
    Join Date
    12-06-2006
    Location
    Mississauga, CANADA
    MS-Off Ver
    2003:2010
    Posts
    34,898

    Re: Replace Countifs (Excel 2007) with Sumproduct (Excel 2003)

    Try:

    =SUMPRODUCT(--($a$1:$a$200>="01/01/2012"+0),--($a$1:$a$200<="31/1/2012"+0),--($b$10:$b$200="YES"))
    Where there is a will there are many ways.

    If you are happy with the results, please add to the contributor's reputation by clicking the reputation icon (star icon) below left corner

    Please also mark the thread as Solved once it is solved. Check the FAQ's to see how.

  3. #3
    Forum Expert OnErrorGoto0's Avatar
    Join Date
    12-30-2011
    Location
    I DO NOT POST HERE ANYMORE
    MS-Off Ver
    I DO NOT POST HERE ANYMORE
    Posts
    1,655

    Re: Replace Countifs (Excel 2007) with Sumproduct (Excel 2003)

    =SUMPRODUCT(($a$1:$a$200>=date(2012,1,1))*($a$1:$a$200<=date(2012,1,31))*($b$10:$b$200="YES"))
    should do it.
    Good luck.

  4. #4
    Registered User
    Join Date
    01-16-2012
    Location
    Orkney
    MS-Off Ver
    Excel 2007
    Posts
    3

    Re: Replace Countifs (Excel 2007) with Sumproduct (Excel 2003)

    Many thanks to you both. 0EGO, thanks for your speedy response to my inadvertantly wrongly placed original response.
    Regards
    Terry

  5. #5
    Forum Expert OnErrorGoto0's Avatar
    Join Date
    12-30-2011
    Location
    I DO NOT POST HERE ANYMORE
    MS-Off Ver
    I DO NOT POST HERE ANYMORE
    Posts
    1,655

    Re: Replace Countifs (Excel 2007) with Sumproduct (Excel 2003)

    My pleasure.

+ 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