+ Reply to Thread
Results 1 to 10 of 10

Counting Dates in a Range

  1. #1
    Matt7102
    Guest

    Counting Dates in a Range

    I seek help to find a formula to do the following:
    I have a range (P2:AB659) that is populated with dates entered 1/16/06
    format and displayed as 6-Jan format. I need to count the number of cells
    containing any date in January, any date in February, etc.

    TIA, Matt



  2. #2
    Sloth
    Guest

    RE: Counting Dates in a Range

    =SUMPRODUCT(--(MONTH(P2:AB659)=1)

    change the 1 to the month number you want to count (ie. Jan=1, Feb=2, Mar=3,
    etc.)

    "Matt7102" wrote:

    > I seek help to find a formula to do the following:
    > I have a range (P2:AB659) that is populated with dates entered 1/16/06
    > format and displayed as 6-Jan format. I need to count the number of cells
    > containing any date in January, any date in February, etc.
    >
    > TIA, Matt
    >
    >


  3. #3
    Bean123r
    Guest

    RE: Counting Dates in a Range

    What is the purpose/meaning of the double dash (--) in this formula?

    Thanks

    "Sloth" wrote:

    > =SUMPRODUCT(--(MONTH(P2:AB659)=1)
    >
    > change the 1 to the month number you want to count (ie. Jan=1, Feb=2, Mar=3,
    > etc.)
    >
    > "Matt7102" wrote:
    >
    > > I seek help to find a formula to do the following:
    > > I have a range (P2:AB659) that is populated with dates entered 1/16/06
    > > format and displayed as 6-Jan format. I need to count the number of cells
    > > containing any date in January, any date in February, etc.
    > >
    > > TIA, Matt
    > >
    > >


  4. #4
    Sloth
    Guest

    RE: Counting Dates in a Range

    It turns an array of logical terms into 1's and 0's. This way they can be
    summed (TRUE/FALSE is ignored when summing).

    Example:
    {TRUE,TRUE,FALSE,TRUE}->{1,1,0,1}

    NOTE: The formula is missing a close parenthesis and should be

    =SUMPRODUCT(--(MONTH(P2:AB659)=1))

    "Bean123r" wrote:

    > What is the purpose/meaning of the double dash (--) in this formula?
    >
    > Thanks
    >
    > "Sloth" wrote:
    >
    > > =SUMPRODUCT(--(MONTH(P2:AB659)=1)
    > >
    > > change the 1 to the month number you want to count (ie. Jan=1, Feb=2, Mar=3,
    > > etc.)
    > >
    > > "Matt7102" wrote:
    > >
    > > > I seek help to find a formula to do the following:
    > > > I have a range (P2:AB659) that is populated with dates entered 1/16/06
    > > > format and displayed as 6-Jan format. I need to count the number of cells
    > > > containing any date in January, any date in February, etc.
    > > >
    > > > TIA, Matt
    > > >
    > > >


  5. #5
    Matt7102
    Guest

    RE: Counting Dates in a Range

    Thanks for the help, and the short tutorial on explaining the formula
    function... however, using a smaller dataset to test, the formula does not
    return the correct result for January. Works fine for all other months.
    When I add a date in the range other than January to the test dataset, (or
    delete an existing) all is well for the month altered. January is just NOT
    working...any ideas?

    "Sloth" wrote:

    > It turns an array of logical terms into 1's and 0's. This way they can be
    > summed (TRUE/FALSE is ignored when summing).
    >
    > Example:
    > {TRUE,TRUE,FALSE,TRUE}->{1,1,0,1}
    >
    > NOTE: The formula is missing a close parenthesis and should be
    >
    > =SUMPRODUCT(--(MONTH(P2:AB659)=1))
    >
    > "Bean123r" wrote:
    >
    > > What is the purpose/meaning of the double dash (--) in this formula?
    > >
    > > Thanks
    > >
    > > "Sloth" wrote:
    > >
    > > > =SUMPRODUCT(--(MONTH(P2:AB659)=1)
    > > >
    > > > change the 1 to the month number you want to count (ie. Jan=1, Feb=2, Mar=3,
    > > > etc.)
    > > >
    > > > "Matt7102" wrote:
    > > >
    > > > > I seek help to find a formula to do the following:
    > > > > I have a range (P2:AB659) that is populated with dates entered 1/16/06
    > > > > format and displayed as 6-Jan format. I need to count the number of cells
    > > > > containing any date in January, any date in February, etc.
    > > > >
    > > > > TIA, Matt
    > > > >
    > > > >


  6. #6
    Sloth
    Guest

    RE: Counting Dates in a Range

    I have no idea why it wouldn't be working. I made a small list to test that
    worked fine. Can you show the list, formulas, and results? Is it giving an
    error, or the wrong value? What value does the formula produce? What value
    should it be?

    "Matt7102" wrote:

    > Thanks for the help, and the short tutorial on explaining the formula
    > function... however, using a smaller dataset to test, the formula does not
    > return the correct result for January. Works fine for all other months.
    > When I add a date in the range other than January to the test dataset, (or
    > delete an existing) all is well for the month altered. January is just NOT
    > working...any ideas?
    >
    > "Sloth" wrote:
    >
    > > It turns an array of logical terms into 1's and 0's. This way they can be
    > > summed (TRUE/FALSE is ignored when summing).
    > >
    > > Example:
    > > {TRUE,TRUE,FALSE,TRUE}->{1,1,0,1}
    > >
    > > NOTE: The formula is missing a close parenthesis and should be
    > >
    > > =SUMPRODUCT(--(MONTH(P2:AB659)=1))
    > >
    > > "Bean123r" wrote:
    > >
    > > > What is the purpose/meaning of the double dash (--) in this formula?
    > > >
    > > > Thanks
    > > >
    > > > "Sloth" wrote:
    > > >
    > > > > =SUMPRODUCT(--(MONTH(P2:AB659)=1)
    > > > >
    > > > > change the 1 to the month number you want to count (ie. Jan=1, Feb=2, Mar=3,
    > > > > etc.)
    > > > >
    > > > > "Matt7102" wrote:
    > > > >
    > > > > > I seek help to find a formula to do the following:
    > > > > > I have a range (P2:AB659) that is populated with dates entered 1/16/06
    > > > > > format and displayed as 6-Jan format. I need to count the number of cells
    > > > > > containing any date in January, any date in February, etc.
    > > > > >
    > > > > > TIA, Matt
    > > > > >
    > > > > >


  7. #7
    Matt7102
    Guest

    RE: Counting Dates in a Range

    Well, I cannot attach the data set, so here is an example: With only a
    single column of the range populated:
    P
    2) 1-Jan =SUMPRODUCT(--(MONTH($P$2:$Y$14)=1))
    3) 1-Feb =SUMPRODUCT(--(MONTH($P$2:$Y$14)=2))
    4) 1-Mar =SUMPRODUCT(--(MONTH($P$2:$Y$14)=3))

    Etc thru 1-Dec, formula contnues as well. Jan returns 119, all others
    return 1. If I change 1-Jan to 1-Jun, June formula result changes to 2, and
    January changes to 118. If I change all 12 to 1-Jan, January result is 130,
    all other results are zero. If I then clear contents, Jan result is 130, all
    other results are zero.

    Thanks again, Matt




    "Sloth" wrote:

    > I have no idea why it wouldn't be working. I made a small list to test that
    > worked fine. Can you show the list, formulas, and results? Is it giving an
    > error, or the wrong value? What value does the formula produce? What value
    > should it be?
    >
    > "Matt7102" wrote:
    >
    > > Thanks for the help, and the short tutorial on explaining the formula
    > > function... however, using a smaller dataset to test, the formula does not
    > > return the correct result for January. Works fine for all other months.
    > > When I add a date in the range other than January to the test dataset, (or
    > > delete an existing) all is well for the month altered. January is just NOT
    > > working...any ideas?
    > >
    > > "Sloth" wrote:
    > >
    > > > It turns an array of logical terms into 1's and 0's. This way they can be
    > > > summed (TRUE/FALSE is ignored when summing).
    > > >
    > > > Example:
    > > > {TRUE,TRUE,FALSE,TRUE}->{1,1,0,1}
    > > >
    > > > NOTE: The formula is missing a close parenthesis and should be
    > > >
    > > > =SUMPRODUCT(--(MONTH(P2:AB659)=1))
    > > >
    > > > "Bean123r" wrote:
    > > >
    > > > > What is the purpose/meaning of the double dash (--) in this formula?
    > > > >
    > > > > Thanks
    > > > >
    > > > > "Sloth" wrote:
    > > > >
    > > > > > =SUMPRODUCT(--(MONTH(P2:AB659)=1)
    > > > > >
    > > > > > change the 1 to the month number you want to count (ie. Jan=1, Feb=2, Mar=3,
    > > > > > etc.)
    > > > > >
    > > > > > "Matt7102" wrote:
    > > > > >
    > > > > > > I seek help to find a formula to do the following:
    > > > > > > I have a range (P2:AB659) that is populated with dates entered 1/16/06
    > > > > > > format and displayed as 6-Jan format. I need to count the number of cells
    > > > > > > containing any date in January, any date in February, etc.
    > > > > > >
    > > > > > > TIA, Matt
    > > > > > >
    > > > > > >


  8. #8
    Matt7102
    Guest

    RE: Counting Dates in a Range

    I just figured out that the cell range is 130 cells, and entering any date
    reduces the <blank> cell count by one- Jan formula is counting blank cells
    perhaps?

    "Sloth" wrote:

    > I have no idea why it wouldn't be working. I made a small list to test that
    > worked fine. Can you show the list, formulas, and results? Is it giving an
    > error, or the wrong value? What value does the formula produce? What value
    > should it be?
    >
    > "Matt7102" wrote:
    >
    > > Thanks for the help, and the short tutorial on explaining the formula
    > > function... however, using a smaller dataset to test, the formula does not
    > > return the correct result for January. Works fine for all other months.
    > > When I add a date in the range other than January to the test dataset, (or
    > > delete an existing) all is well for the month altered. January is just NOT
    > > working...any ideas?
    > >
    > > "Sloth" wrote:
    > >
    > > > It turns an array of logical terms into 1's and 0's. This way they can be
    > > > summed (TRUE/FALSE is ignored when summing).
    > > >
    > > > Example:
    > > > {TRUE,TRUE,FALSE,TRUE}->{1,1,0,1}
    > > >
    > > > NOTE: The formula is missing a close parenthesis and should be
    > > >
    > > > =SUMPRODUCT(--(MONTH(P2:AB659)=1))
    > > >
    > > > "Bean123r" wrote:
    > > >
    > > > > What is the purpose/meaning of the double dash (--) in this formula?
    > > > >
    > > > > Thanks
    > > > >
    > > > > "Sloth" wrote:
    > > > >
    > > > > > =SUMPRODUCT(--(MONTH(P2:AB659)=1)
    > > > > >
    > > > > > change the 1 to the month number you want to count (ie. Jan=1, Feb=2, Mar=3,
    > > > > > etc.)
    > > > > >
    > > > > > "Matt7102" wrote:
    > > > > >
    > > > > > > I seek help to find a formula to do the following:
    > > > > > > I have a range (P2:AB659) that is populated with dates entered 1/16/06
    > > > > > > format and displayed as 6-Jan format. I need to count the number of cells
    > > > > > > containing any date in January, any date in February, etc.
    > > > > > >
    > > > > > > TIA, Matt
    > > > > > >
    > > > > > >


  9. #9
    Sloth
    Guest

    RE: Counting Dates in a Range

    Good problem solving, I didn't realise you had blank cells. Try these
    formulas.

    =SUMPRODUCT(--(MONTH(range)=1),1-(ISBLANK(range)))
    or
    =SUMPRODUCT(--(MONTH(range)=1),--(ISNUMBER(range)))

    "Matt7102" wrote:

    > I just figured out that the cell range is 130 cells, and entering any date
    > reduces the <blank> cell count by one- Jan formula is counting blank cells
    > perhaps?
    >
    > "Sloth" wrote:
    >
    > > I have no idea why it wouldn't be working. I made a small list to test that
    > > worked fine. Can you show the list, formulas, and results? Is it giving an
    > > error, or the wrong value? What value does the formula produce? What value
    > > should it be?
    > >
    > > "Matt7102" wrote:
    > >
    > > > Thanks for the help, and the short tutorial on explaining the formula
    > > > function... however, using a smaller dataset to test, the formula does not
    > > > return the correct result for January. Works fine for all other months.
    > > > When I add a date in the range other than January to the test dataset, (or
    > > > delete an existing) all is well for the month altered. January is just NOT
    > > > working...any ideas?
    > > >
    > > > "Sloth" wrote:
    > > >
    > > > > It turns an array of logical terms into 1's and 0's. This way they can be
    > > > > summed (TRUE/FALSE is ignored when summing).
    > > > >
    > > > > Example:
    > > > > {TRUE,TRUE,FALSE,TRUE}->{1,1,0,1}
    > > > >
    > > > > NOTE: The formula is missing a close parenthesis and should be
    > > > >
    > > > > =SUMPRODUCT(--(MONTH(P2:AB659)=1))
    > > > >
    > > > > "Bean123r" wrote:
    > > > >
    > > > > > What is the purpose/meaning of the double dash (--) in this formula?
    > > > > >
    > > > > > Thanks
    > > > > >
    > > > > > "Sloth" wrote:
    > > > > >
    > > > > > > =SUMPRODUCT(--(MONTH(P2:AB659)=1)
    > > > > > >
    > > > > > > change the 1 to the month number you want to count (ie. Jan=1, Feb=2, Mar=3,
    > > > > > > etc.)
    > > > > > >
    > > > > > > "Matt7102" wrote:
    > > > > > >
    > > > > > > > I seek help to find a formula to do the following:
    > > > > > > > I have a range (P2:AB659) that is populated with dates entered 1/16/06
    > > > > > > > format and displayed as 6-Jan format. I need to count the number of cells
    > > > > > > > containing any date in January, any date in February, etc.
    > > > > > > >
    > > > > > > > TIA, Matt
    > > > > > > >
    > > > > > > >


  10. #10
    Matt7102
    Guest

    RE: Counting Dates in a Range

    Thanks for the assistance, it now works without error. Hope I can pass along
    similar help someday!

    Matt

    "Sloth" wrote:

    > Good problem solving, I didn't realise you had blank cells. Try these
    > formulas.
    >
    > =SUMPRODUCT(--(MONTH(range)=1),1-(ISBLANK(range)))
    > or
    > =SUMPRODUCT(--(MONTH(range)=1),--(ISNUMBER(range)))
    >
    > "Matt7102" wrote:
    >
    > > I just figured out that the cell range is 130 cells, and entering any date
    > > reduces the <blank> cell count by one- Jan formula is counting blank cells
    > > perhaps?
    > >
    > > "Sloth" wrote:
    > >
    > > > I have no idea why it wouldn't be working. I made a small list to test that
    > > > worked fine. Can you show the list, formulas, and results? Is it giving an
    > > > error, or the wrong value? What value does the formula produce? What value
    > > > should it be?
    > > >
    > > > "Matt7102" wrote:
    > > >
    > > > > Thanks for the help, and the short tutorial on explaining the formula
    > > > > function... however, using a smaller dataset to test, the formula does not
    > > > > return the correct result for January. Works fine for all other months.
    > > > > When I add a date in the range other than January to the test dataset, (or
    > > > > delete an existing) all is well for the month altered. January is just NOT
    > > > > working...any ideas?
    > > > >
    > > > > "Sloth" wrote:
    > > > >
    > > > > > It turns an array of logical terms into 1's and 0's. This way they can be
    > > > > > summed (TRUE/FALSE is ignored when summing).
    > > > > >
    > > > > > Example:
    > > > > > {TRUE,TRUE,FALSE,TRUE}->{1,1,0,1}
    > > > > >
    > > > > > NOTE: The formula is missing a close parenthesis and should be
    > > > > >
    > > > > > =SUMPRODUCT(--(MONTH(P2:AB659)=1))
    > > > > >
    > > > > > "Bean123r" wrote:
    > > > > >
    > > > > > > What is the purpose/meaning of the double dash (--) in this formula?
    > > > > > >
    > > > > > > Thanks
    > > > > > >
    > > > > > > "Sloth" wrote:
    > > > > > >
    > > > > > > > =SUMPRODUCT(--(MONTH(P2:AB659)=1)
    > > > > > > >
    > > > > > > > change the 1 to the month number you want to count (ie. Jan=1, Feb=2, Mar=3,
    > > > > > > > etc.)
    > > > > > > >
    > > > > > > > "Matt7102" wrote:
    > > > > > > >
    > > > > > > > > I seek help to find a formula to do the following:
    > > > > > > > > I have a range (P2:AB659) that is populated with dates entered 1/16/06
    > > > > > > > > format and displayed as 6-Jan format. I need to count the number of cells
    > > > > > > > > containing any date in January, any date in February, etc.
    > > > > > > > >
    > > > > > > > > TIA, Matt
    > > > > > > > >
    > > > > > > > >


+ 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