Results 1 to 6 of 6
  1. #1
    Bronze Lounger
    Join Date
    Jan 2001
    Posts
    1,418
    Thanks
    1
    Thanked 0 Times in 0 Posts

    Days Of Month (2000)

    In column a1:a6, I have listed the months of November 03-April 04, months during which I am obligated to purchase a minimum quantity of a product on a daily basis. In column b1:b6, I have the minimum daily quantitites listed. For example, in cell a1, I have "November 03", and in b1, a quantity of 10,000, the amount I am obligated to purchase each day during November 03. What I want to do is at cell b7, sum the totals of the daily minimum quantities for all of the months listed, i. e., November 03-April 04. For example, the total quantity for November would be 10,000*30, or 300,000. I would like one formula in cell b7 to total all of the months.
    Thanks,
    Jeff

  2. #2
    WS Lounge VIP sdckapr's Avatar
    Join Date
    Jul 2002
    Location
    Pittsburgh, Pennsylvania, USA
    Posts
    11,225
    Thanks
    14
    Thanked 342 Times in 335 Posts

    Re: Days Of Month (2000)

    Try this ARRAY formula (confirm with ctrl-shift-enter):
    =SUM((DATE(YEAR(A1:A6),MONTH(A1:A6)+1,1)-DATE(YEAR(A1:A6),MONTH(A1:A6),1))*B1:B6)

    Steve

  3. #3
    Bronze Lounger
    Join Date
    Jan 2001
    Posts
    1,418
    Thanks
    1
    Thanked 0 Times in 0 Posts

    Re: Days Of Month (2000)

    Yep-sure does the trick. Thanks! I was trying to use the day(eomonth() argumant but was getting all balled up! How does yours work?
    Thanks,
    Jeff

  4. #4
    WS Lounge VIP sdckapr's Avatar
    Join Date
    Jul 2002
    Location
    Pittsburgh, Pennsylvania, USA
    Posts
    11,225
    Thanks
    14
    Thanked 342 Times in 335 Posts

    Re: Days Of Month (2000)

    =SUM((DATE(YEAR(A1:A6),MONTH(A1:A6)+1,1)-DATE(YEAR(A1:A6),MONTH(A1:A6),1))*B1:B6)

    Take the first day of the NEXT month:
    DATE(YEAR(A1:A6),MONTH(A1:A6)+1,1)

    Subtract from it the first day of month
    -DATE(YEAR(A1:A6),MONTH(A1:A6),1)

    This gives the number of days in the month.
    Multiply this number by the value in COl B

    The array formula makes it an array of 6 rows and the SUM adds them up

    Steve

  5. #5
    Bronze Lounger
    Join Date
    Jan 2001
    Posts
    1,418
    Thanks
    1
    Thanked 0 Times in 0 Posts

    Re: Days Of Month (2000)

    Thanks, Steve. I'll try and remember this "shortcut"!
    Jeff

  6. #6
    Uranium Lounger
    Join Date
    Jan 2001
    Location
    South Carolina, USA
    Posts
    7,295
    Thanks
    0
    Thanked 0 Times in 0 Posts

    Re: Days Of Month (2000)

    Slightly simpler than Steve's formula:

    <pre>=DAY(DATE(YEAR(A1:A6),MONTH(A1:A6)+1,0))*B1:B 6
    </pre>


    Also an array formula that must be confirmed with Ctrl+Shift+Enter
    Legare Coleman

Posting Permissions

  • You may not post new threads
  • You may not post replies
  • You may not post attachments
  • You may not edit your posts
  •