+ Reply to Thread
Results 1 to 7 of 7

Problem with sumproduct and month=1

  1. #1
    bobh727
    Guest

    Problem with sumproduct and month=1

    I am using the following formula to count the number of entries by month in a
    log.
    =SUMPRODUCT(--(MONTH(DATA!A2:A2019)=1))
    All of the other months sum correctly except month 1 which counts all
    January entries and then all blank cells in the range--that is, cells A1600
    to A2019 are blank, waiting for future date entries.

    Ideas, suggestions, help--all welcome here!

  2. #2
    Dave R.
    Guest

    Re: Problem with sumproduct and month=1

    Ahh, it counts the blanks as 0s which is a January date a long time ago. Try
    this;

    =SUMPRODUCT(--ISNUMBER(A2:A2019),--(MONTH(A2:A2019)=1))


    "bobh727" <[email protected]> wrote in message
    news:[email protected]...
    > I am using the following formula to count the number of entries by month

    in a
    > log.
    > =SUMPRODUCT(--(MONTH(DATA!A2:A2019)=1))
    > All of the other months sum correctly except month 1 which counts all
    > January entries and then all blank cells in the range--that is, cells

    A1600
    > to A2019 are blank, waiting for future date entries.
    >
    > Ideas, suggestions, help--all welcome here!




  3. #3
    Peo Sjoblom
    Guest

    Re: Problem with sumproduct and month=1

    It's because the first date in the date function is January 0 1900 thanks to
    a bug in Lotus that MS copied
    You need to qualify that it is a number for January, i.e.

    =SUMPRODUCT(--(MONTH(DATA!A2:A2019)=1),--(DATA!A2:A2019)<>"")

    will work for January

    --
    Regards,

    Peo Sjoblom

    (No private emails please, for everyone's
    benefit keep the discussion in the newsgroup/forum)



    "bobh727" <[email protected]> wrote in message
    news:[email protected]...
    >I am using the following formula to count the number of entries by month in
    >a
    > log.
    > =SUMPRODUCT(--(MONTH(DATA!A2:A2019)=1))
    > All of the other months sum correctly except month 1 which counts all
    > January entries and then all blank cells in the range--that is, cells
    > A1600
    > to A2019 are blank, waiting for future date entries.
    >
    > Ideas, suggestions, help--all welcome here!




  4. #4
    Aladin Akyurek
    Guest

    Re: Problem with sumproduct and month=1

    =SUMPRODUCT(--(MONTH(DATA!A2:A2019)=1),--(YEAR(DATA!A2:A2019)=2005),--(ISNUMBER(DATA!A2:A2019))

    bobh727 wrote:
    > I am using the following formula to count the number of entries by month in a
    > log.
    > =SUMPRODUCT(--(MONTH(DATA!A2:A2019)=1))
    > All of the other months sum correctly except month 1 which counts all
    > January entries and then all blank cells in the range--that is, cells A1600
    > to A2019 are blank, waiting for future date entries.
    >
    > Ideas, suggestions, help--all welcome here!


  5. #5
    PeterAtherton
    Guest

    RE: Problem with sumproduct and month=1

    Perhaps an array formula would do something like

    =COUNT(AND(MONTH(A2:A200=1),ISNUMBER(A2:A200)),A2,A200) and entered as Ctl+
    Shift+ Enter.

    Regards
    Peter

    "bobh727" wrote:

    > I am using the following formula to count the number of entries by month in a
    > log.
    > =SUMPRODUCT(--(MONTH(DATA!A2:A2019)=1))
    > All of the other months sum correctly except month 1 which counts all
    > January entries and then all blank cells in the range--that is, cells A1600
    > to A2019 are blank, waiting for future date entries.
    >
    > Ideas, suggestions, help--all welcome here!


  6. #6
    bobh727
    Guest

    RE: Problem with sumproduct and month=1

    THANKS!!!! To all of you--I am overwhelmed!!!

    "bobh727" wrote:

    > I am using the following formula to count the number of entries by month in a
    > log.
    > =SUMPRODUCT(--(MONTH(DATA!A2:A2019)=1))
    > All of the other months sum correctly except month 1 which counts all
    > January entries and then all blank cells in the range--that is, cells A1600
    > to A2019 are blank, waiting for future date entries.
    >
    > Ideas, suggestions, help--all welcome here!


  7. #7
    Stan Leeds
    Guest

    Re: Problem with sumproduct and month=1

    bobh727 wrote:
    > THANKS!!!! To all of you--I am overwhelmed!!!
    >
    > "bobh727" wrote:
    >
    >
    >>I am using the following formula to count the number of entries by month in a
    >>log.
    >> =SUMPRODUCT(--(MONTH(DATA!A2:A2019)=1))
    >> All of the other months sum correctly except month 1 which counts all
    >>January entries and then all blank cells in the range--that is, cells A1600
    >>to A2019 are blank, waiting for future date entries.
    >>
    >>Ideas, suggestions, help--all welcome here!


    Just want to say thanks also.

    Through this thread and assorted others, I found an answer to my problem.

    I have a column of dates and then two columns of seperate expenditures.

    I wanted to sum up the individual expenses by month by expenditure.

    Date Spend1 Spend2
    1/1/2005 $100.00 $30.00
    2/14/2005 $50.00
    3/15/2005 $25.00
    etc..

    I used
    =SUMPRODUCT(--(MONTH(A2:A100)=2),--(A2:A100<>"")*(C2:C100)). It
    verifies that it is only checking cells with filled in dates and not
    blanks, then sums up the cells C3:C100 or B3:B100, depending on which
    one I need. The =4 is for the month of April.

    Thanks again,

    Stan

+ 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