+ Reply to Thread
Results 1 to 6 of 6

Need assistance: Count non-blank within date range

  1. #1
    Paul
    Guest

    Need assistance: Count non-blank within date range

    I am building a call log sheet for a friend. He needs to log each phone call
    he makes each month, and track numbers of call-back requests.

    There are 2 columns in question. Column E is the date that the phone call
    was originally made. Every used row will have a date in col E. Column F
    contains a note related to the call-back request. If there is no further
    action required, the cell in col F will be blank.

    My goal is to have a function (probably array function) to count the number
    of non-blank cells in col F for each month, as noted in col E of the phone
    call date. The analysis will appear on a separate sheet.

    Example source data:
    E F
    2/1/2006 call back 5/4
    2/1/2006
    2/16/2006 send fax
    2/27/2006
    3/1/2006
    3/7/2006 call back 4/1
    3/8/2006 email pricelist
    3/9/2006
    3/14/2006
    3/18/2006 call back 5/12

    Example Results:

    Feb. 2006: 2
    Mar. 2006: 3

    I am currently using array function
    {=SUM((MONTH(Data!$E$3:$E$6000)=$A3)*(YEAR(Data!$E$3:$E$6000)=$A$2))} to
    simply count the number of calls made, but am stumped as far as counting
    non-blank cells adjacent to this column.

    Thank you for your assistance.





  2. #2
    Bernard Liengme
    Guest

    Re: Need assistance: Count non-blank within date range

    Time to meet SUMPRODUCT

    In place of
    {=SUM((MONTH(Data!$E$3:$E$6000)=$A3)*(YEAR(Data!$E$3:$E$6000)=$A$2))} Use
    =SUMPRODUCT
    (--(MONTH(Data!$E$3:$E$6000)=$A3), --(YEAR(Data!$E$3:$E$6000)=$A$2)) This
    is NOT an array formula so just complete it with ENTER

    For non-blanks
    =SUMPRODUCT
    (--(MONTH(Data!$E$3:$E$6000)=$A3), --(YEAR(Data!$E$3:$E$6000)=$A$2), --(Data!$F$3:$F$6000>""))

    For more info see
    http://www.xldynamic.com/source/xld.SUMPRODUCT.html
    explains the "--":
    http://mcgimpsey.com/excel/formulae/doubleneg.html


    best wishes
    --
    Bernard V Liengme
    www.stfx.ca/people/bliengme
    remove caps from email

    "Paul" <[email protected]> wrote in message
    news:%[email protected]...
    >I am building a call log sheet for a friend. He needs to log each phone
    >call he makes each month, and track numbers of call-back requests.
    >
    > There are 2 columns in question. Column E is the date that the phone call
    > was originally made. Every used row will have a date in col E. Column F
    > contains a note related to the call-back request. If there is no further
    > action required, the cell in col F will be blank.
    >
    > My goal is to have a function (probably array function) to count the
    > number of non-blank cells in col F for each month, as noted in col E of
    > the phone call date. The analysis will appear on a separate sheet.
    >
    > Example source data:
    > E F
    > 2/1/2006 call back 5/4
    > 2/1/2006
    > 2/16/2006 send fax
    > 2/27/2006
    > 3/1/2006
    > 3/7/2006 call back 4/1
    > 3/8/2006 email pricelist
    > 3/9/2006
    > 3/14/2006
    > 3/18/2006 call back 5/12
    >
    > Example Results:
    >
    > Feb. 2006: 2
    > Mar. 2006: 3
    >
    > I am currently using array function
    > {=SUM((MONTH(Data!$E$3:$E$6000)=$A3)*(YEAR(Data!$E$3:$E$6000)=$A$2))} to
    > simply count the number of calls made, but am stumped as far as counting
    > non-blank cells adjacent to this column.
    >
    > Thank you for your assistance.
    >
    >
    >
    >




  3. #3
    Valued Forum Contributor
    Join Date
    03-25-2004
    Location
    Boston, MA US
    Posts
    1,094
    SUMPRODUCT should work.

    =SUMPRODUCT(--(MONTH(E1:E9)=1),--(YEAR(E1:E9)=2006),--(F1:F9<>""))

    This is for January 2006. You need to change the MONTH()=1 number for each month accordingly, Feb = 2, March = 3 and so on. You could put the numbers in a reference cell and have it refer to that instead.

    Does that help?

    Steve

  4. #4
    Kevin Vaughn
    Guest

    RE: Need assistance: Count non-blank within date range

    On my test range, this worked:

    SUMPRODUCT(--(MONTH(Data!$E$1:$E$10)=MONTH(Test!$A3)),--(YEAR(Data!$E$1:$E$10)=YEAR(Test!$A3)),--(Data!$F$1:$F$10<>""))

    --
    Kevin Vaughn


    "Paul" wrote:

    > I am building a call log sheet for a friend. He needs to log each phone call
    > he makes each month, and track numbers of call-back requests.
    >
    > There are 2 columns in question. Column E is the date that the phone call
    > was originally made. Every used row will have a date in col E. Column F
    > contains a note related to the call-back request. If there is no further
    > action required, the cell in col F will be blank.
    >
    > My goal is to have a function (probably array function) to count the number
    > of non-blank cells in col F for each month, as noted in col E of the phone
    > call date. The analysis will appear on a separate sheet.
    >
    > Example source data:
    > E F
    > 2/1/2006 call back 5/4
    > 2/1/2006
    > 2/16/2006 send fax
    > 2/27/2006
    > 3/1/2006
    > 3/7/2006 call back 4/1
    > 3/8/2006 email pricelist
    > 3/9/2006
    > 3/14/2006
    > 3/18/2006 call back 5/12
    >
    > Example Results:
    >
    > Feb. 2006: 2
    > Mar. 2006: 3
    >
    > I am currently using array function
    > {=SUM((MONTH(Data!$E$3:$E$6000)=$A3)*(YEAR(Data!$E$3:$E$6000)=$A$2))} to
    > simply count the number of calls made, but am stumped as far as counting
    > non-blank cells adjacent to this column.
    >
    > Thank you for your assistance.
    >
    >
    >
    >
    >


  5. #5
    Paul
    Guest

    Re: Need assistance: Count non-blank within date range

    Bernard, Kevin and Steve - Thank you for your replies. SUMPRODUCT seems to
    do exactly what I need. I'll have to research that function further to see
    what other applications it may have in my work.

    Thanks again.
    Paul



  6. #6
    Kevin Vaughn
    Guest

    Re: Need assistance: Count non-blank within date range

    Here is a link to an explanation of sumproduct. I had no idea how to use it
    before I read this page:

    http://www.xldynamic.com/source/xld.SUMPRODUCT.html

    --
    Kevin Vaughn


    "Paul" wrote:

    > Bernard, Kevin and Steve - Thank you for your replies. SUMPRODUCT seems to
    > do exactly what I need. I'll have to research that function further to see
    > what other applications it may have in my work.
    >
    > Thanks again.
    > Paul
    >
    >
    >


+ 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