+ Reply to Thread
Results 1 to 11 of 11

count dates within range by year and month

  1. #1
    Isaiah25
    Guest

    count dates within range by year and month

    Column D contains a large number of rows of dates (in random order).
    Column F contains a text status ("open" or "closed").

    I would like to create a series of four columns:

    01/2005 10 8 2
    02/2005 12 9 3
    03/2005 11 7 4

    wherein:
    the first column is the criterion for counting,
    the second column is the number of entries for the target month,
    the third column is the number of open cases, and
    the fourth column is the number of closed cases.



  2. #2
    Don Guillett
    Guest

    Re: count dates within range by year and month

    try something like this
    =sumproduct((month(daterng)=month(a2))*(year(daterng)=year(a2))*(statusrng="
    open"))

    --
    Don Guillett
    SalesAid Software
    [email protected]
    "Isaiah25" <[email protected]> wrote in message
    news:[email protected]...
    > Column D contains a large number of rows of dates (in random order).
    > Column F contains a text status ("open" or "closed").
    >
    > I would like to create a series of four columns:
    >
    > 01/2005 10 8 2
    > 02/2005 12 9 3
    > 03/2005 11 7 4
    >
    > wherein:
    > the first column is the criterion for counting,
    > the second column is the number of entries for the target month,
    > the third column is the number of open cases, and
    > the fourth column is the number of closed cases.
    >
    >




  3. #3
    Bob Phillips
    Guest

    Re: count dates within range by year and month

    Assuming the columns are on another sheet in A1:D1, etc

    A1: test date
    B1: =SUMPRODUCT(--(MONTH(Sheet1!D1:D100)=MONTH(A1))
    C1:
    =SUMPRODUCT(--(MONTH(Sheet1!D1:D100)=MONTH(A1),--(Sheet1!F1:F100="open"))
    D1: =B1-C1

    and copy down

    --
    HTH

    Bob Phillips

    "Isaiah25" <[email protected]> wrote in message
    news:[email protected]...
    > Column D contains a large number of rows of dates (in random order).
    > Column F contains a text status ("open" or "closed").
    >
    > I would like to create a series of four columns:
    >
    > 01/2005 10 8 2
    > 02/2005 12 9 3
    > 03/2005 11 7 4
    >
    > wherein:
    > the first column is the criterion for counting,
    > the second column is the number of entries for the target month,
    > the third column is the number of open cases, and
    > the fourth column is the number of closed cases.
    >
    >




  4. #4
    Isaiah25
    Guest

    RE: count dates within range by year and month

    Don's solution worked... Thank you. I also tried Bob's and ran into an
    issue when I tried to incorporate YEAR into the same logic. I have learned
    from you both, and thank you both VERY MUCH for your quick responses.

    Thank you.

    "Isaiah25" wrote:

    > Column D contains a large number of rows of dates (in random order).
    > Column F contains a text status ("open" or "closed").
    >
    > I would like to create a series of four columns:
    >
    > 01/2005 10 8 2
    > 02/2005 12 9 3
    > 03/2005 11 7 4
    >
    > wherein:
    > the first column is the criterion for counting,
    > the second column is the number of entries for the target month,
    > the third column is the number of open cases, and
    > the fourth column is the number of closed cases.
    >
    >


  5. #5
    Bob Phillips
    Guest

    Re: count dates within range by year and month

    It would just be

    =SUMPRODUCT(--(MONTH(Sheet1!D1:D100)=MONTH(A1)),--(YEAR(Sheet1!D1:D100)=Year
    (A1)))

    etc.

    --
    HTH

    Bob Phillips

    "Isaiah25" <[email protected]> wrote in message
    news:[email protected]...
    > Don's solution worked... Thank you. I also tried Bob's and ran into an
    > issue when I tried to incorporate YEAR into the same logic. I have

    learned
    > from you both, and thank you both VERY MUCH for your quick responses.
    >
    > Thank you.
    >
    > "Isaiah25" wrote:
    >
    > > Column D contains a large number of rows of dates (in random order).
    > > Column F contains a text status ("open" or "closed").
    > >
    > > I would like to create a series of four columns:
    > >
    > > 01/2005 10 8 2
    > > 02/2005 12 9 3
    > > 03/2005 11 7 4
    > >
    > > wherein:
    > > the first column is the criterion for counting,
    > > the second column is the number of entries for the target month,
    > > the third column is the number of open cases, and
    > > the fourth column is the number of closed cases.
    > >
    > >




  6. #6
    Don Guillett
    Guest

    Re: count dates within range by year and month

    we all aim to please

    --
    Don Guillett
    SalesAid Software
    [email protected]
    "Isaiah25" <[email protected]> wrote in message
    news:[email protected]...
    > Don's solution worked... Thank you. I also tried Bob's and ran into an
    > issue when I tried to incorporate YEAR into the same logic. I have

    learned
    > from you both, and thank you both VERY MUCH for your quick responses.
    >
    > Thank you.
    >
    > "Isaiah25" wrote:
    >
    > > Column D contains a large number of rows of dates (in random order).
    > > Column F contains a text status ("open" or "closed").
    > >
    > > I would like to create a series of four columns:
    > >
    > > 01/2005 10 8 2
    > > 02/2005 12 9 3
    > > 03/2005 11 7 4
    > >
    > > wherein:
    > > the first column is the criterion for counting,
    > > the second column is the number of entries for the target month,
    > > the third column is the number of open cases, and
    > > the fourth column is the number of closed cases.
    > >
    > >




  7. #7
    Isaiah25
    Guest

    Re: count dates within range by year and month

    Is there a way also to do a selective average based on the same data? There
    is a beginning date column and an ending date column for each entry and they
    want an average duration for for all cases in any given month.

    "Don Guillett" wrote:

    > we all aim to please
    >
    > --
    > Don Guillett
    > SalesAid Software
    > [email protected]
    > "Isaiah25" <[email protected]> wrote in message
    > news:[email protected]...
    > > Don's solution worked... Thank you. I also tried Bob's and ran into an
    > > issue when I tried to incorporate YEAR into the same logic. I have

    > learned
    > > from you both, and thank you both VERY MUCH for your quick responses.
    > >
    > > Thank you.
    > >
    > > "Isaiah25" wrote:
    > >
    > > > Column D contains a large number of rows of dates (in random order).
    > > > Column F contains a text status ("open" or "closed").
    > > >
    > > > I would like to create a series of four columns:
    > > >
    > > > 01/2005 10 8 2
    > > > 02/2005 12 9 3
    > > > 03/2005 11 7 4
    > > >
    > > > wherein:
    > > > the first column is the criterion for counting,
    > > > the second column is the number of entries for the target month,
    > > > the third column is the number of open cases, and
    > > > the fourth column is the number of closed cases.
    > > >
    > > >

    >
    >
    >


  8. #8
    Don Guillett
    Guest

    Re: count dates within range by year and month

    Then you have to sum them > count them >divide

    or modify this array formula to suit. Array formulas must be entered/edited
    with ctrl+shift+enter

    =AVERAGE(IF(D1:D5="don",C1:C5))
    --
    Don Guillett
    SalesAid Software
    [email protected]
    "Isaiah25" <[email protected]> wrote in message
    news:[email protected]...
    > Is there a way also to do a selective average based on the same data?

    There
    > is a beginning date column and an ending date column for each entry and

    they
    > want an average duration for for all cases in any given month.
    >
    > "Don Guillett" wrote:
    >
    > > we all aim to please
    > >
    > > --
    > > Don Guillett
    > > SalesAid Software
    > > [email protected]
    > > "Isaiah25" <[email protected]> wrote in message
    > > news:[email protected]...
    > > > Don's solution worked... Thank you. I also tried Bob's and ran into

    an
    > > > issue when I tried to incorporate YEAR into the same logic. I have

    > > learned
    > > > from you both, and thank you both VERY MUCH for your quick responses.
    > > >
    > > > Thank you.
    > > >
    > > > "Isaiah25" wrote:
    > > >
    > > > > Column D contains a large number of rows of dates (in random order).
    > > > > Column F contains a text status ("open" or "closed").
    > > > >
    > > > > I would like to create a series of four columns:
    > > > >
    > > > > 01/2005 10 8 2
    > > > > 02/2005 12 9 3
    > > > > 03/2005 11 7 4
    > > > >
    > > > > wherein:
    > > > > the first column is the criterion for counting,
    > > > > the second column is the number of entries for the target month,
    > > > > the third column is the number of open cases, and
    > > > > the fourth column is the number of closed cases.
    > > > >
    > > > >

    > >
    > >
    > >




  9. #9
    Isaiah25
    Guest

    Re: count dates within range by year and month

    What I'm working with now is:

    =AVERAGE(IF(MONTH('DC NAP NCT Matrix'!D$2:D$1000)=MONTH(A2)*(YEAR('DC NAP
    NCT Matrix'!D$2:D$1000)=YEAR(A2),'DC NAP NCT Matrix'!S$2:SD$1000,))

    where column S is the duration per case.

    "Isaiah25" wrote:

    > Is there a way also to do a selective average based on the same data? There
    > is a beginning date column and an ending date column for each entry and they
    > want an average duration for for all cases in any given month.
    >
    > "Don Guillett" wrote:
    >
    > > we all aim to please
    > >
    > > --
    > > Don Guillett
    > > SalesAid Software
    > > [email protected]
    > > "Isaiah25" <[email protected]> wrote in message
    > > news:[email protected]...
    > > > Don's solution worked... Thank you. I also tried Bob's and ran into an
    > > > issue when I tried to incorporate YEAR into the same logic. I have

    > > learned
    > > > from you both, and thank you both VERY MUCH for your quick responses.
    > > >
    > > > Thank you.
    > > >
    > > > "Isaiah25" wrote:
    > > >
    > > > > Column D contains a large number of rows of dates (in random order).
    > > > > Column F contains a text status ("open" or "closed").
    > > > >
    > > > > I would like to create a series of four columns:
    > > > >
    > > > > 01/2005 10 8 2
    > > > > 02/2005 12 9 3
    > > > > 03/2005 11 7 4
    > > > >
    > > > > wherein:
    > > > > the first column is the criterion for counting,
    > > > > the second column is the number of entries for the target month,
    > > > > the third column is the number of open cases, and
    > > > > the fourth column is the number of closed cases.
    > > > >
    > > > >

    > >
    > >
    > >


  10. #10
    Harlan Grove
    Guest

    Re: count dates within range by year and month

    Bob Phillips wrote...
    ....
    >=SUMPRODUCT(--(MONTH(Sheet1!D1:D100)=MONTH(A1)),
    >--(YEAR(Sheet1!D1:D100)=Year(A1)))

    ....

    Alternative,

    =SUMPRODUCT(--(TEXT(Sheet1!D1:D100,"YYYYMM")=TEXT(A1,"YYYYMM")))


  11. #11
    Bob Phillips
    Guest

    Re: count dates within range by year and month

    You could used this based on Harlan's idea

    =AVERAGE(IF(TEXT(MONTH('DC NAP NCT
    Matrix'!D2:D1000,"YYYYMM")=TEXT(A1,"YYYYMM"),MONTH('DC NAP NCT
    Matrix'!S2:S1000))

    of course still an array formula

    --
    HTH

    Bob Phillips

    "Isaiah25" <[email protected]> wrote in message
    news:[email protected]...
    > What I'm working with now is:
    >
    > =AVERAGE(IF(MONTH('DC NAP NCT Matrix'!D$2:D$1000)=MONTH(A2)*(YEAR('DC NAP
    > NCT Matrix'!D$2:D$1000)=YEAR(A2),'DC NAP NCT Matrix'!S$2:SD$1000,))
    >
    > where column S is the duration per case.
    >
    > "Isaiah25" wrote:
    >
    > > Is there a way also to do a selective average based on the same data?

    There
    > > is a beginning date column and an ending date column for each entry and

    they
    > > want an average duration for for all cases in any given month.
    > >
    > > "Don Guillett" wrote:
    > >
    > > > we all aim to please
    > > >
    > > > --
    > > > Don Guillett
    > > > SalesAid Software
    > > > [email protected]
    > > > "Isaiah25" <[email protected]> wrote in message
    > > > news:[email protected]...
    > > > > Don's solution worked... Thank you. I also tried Bob's and ran

    into an
    > > > > issue when I tried to incorporate YEAR into the same logic. I have
    > > > learned
    > > > > from you both, and thank you both VERY MUCH for your quick

    responses.
    > > > >
    > > > > Thank you.
    > > > >
    > > > > "Isaiah25" wrote:
    > > > >
    > > > > > Column D contains a large number of rows of dates (in random

    order).
    > > > > > Column F contains a text status ("open" or "closed").
    > > > > >
    > > > > > I would like to create a series of four columns:
    > > > > >
    > > > > > 01/2005 10 8 2
    > > > > > 02/2005 12 9 3
    > > > > > 03/2005 11 7 4
    > > > > >
    > > > > > wherein:
    > > > > > the first column is the criterion for counting,
    > > > > > the second column is the number of entries for the target month,
    > > > > > the third column is the number of open cases, and
    > > > > > the fourth column is the number of closed cases.
    > > > > >
    > > > > >
    > > >
    > > >
    > > >




+ 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