+ Reply to Thread
Results 1 to 5 of 5

SUMIF/SUMPRODUCT/IF - 2 criteria - Date and Text

  1. #1
    James T
    Guest

    SUMIF/SUMPRODUCT/IF - 2 criteria - Date and Text

    After reading a few websites I find that SUMIF won't cut it for multiple
    critera. However it appears SUMPRODUCT may do it, but unsure how I achieve
    what I need with SUMPRODUCT.

    Below is the actual table I have in my excel sheet.

    I would like to sum the column RENT/MTH (which is a calculated field RENT/WK
    * 4) if the TYPE = NEW and also if the START DATE is <= to a date in another
    field (lets us say in field B6).

    Pay/Wk Pay/Mth Rent/Wk Rent/Mth Start Date Type
    $200.00 $866.66 $106.00 $459.33 31/08/2005 NEW
    $210.00 $909.99 $138.00 $598.00 31/08/2005 OLD
    $200.00 $866.66 $167.00 $723.66 31/08/2005 BEST

    Can someone help with development of the formula?

    Thanks in advance.

    James

  2. #2
    Arvi Laanemets
    Guest

    Re: SUMIF/SUMPRODUCT/IF - 2 criteria - Date and Text

    Hi

    =SUMPRODUCT(--(Type="NEW"),--(StartDate<=$B$6),RentMth)


    --
    Arvi Laanemets
    ( My real mail address: arvi.laanemets<at>tarkon.ee )



    "James T" <[email protected]> wrote in message
    news:[email protected]...
    > After reading a few websites I find that SUMIF won't cut it for multiple
    > critera. However it appears SUMPRODUCT may do it, but unsure how I
    > achieve
    > what I need with SUMPRODUCT.
    >
    > Below is the actual table I have in my excel sheet.
    >
    > I would like to sum the column RENT/MTH (which is a calculated field
    > RENT/WK
    > * 4) if the TYPE = NEW and also if the START DATE is <= to a date in
    > another
    > field (lets us say in field B6).
    >
    > Pay/Wk Pay/Mth Rent/Wk Rent/Mth Start Date Type
    > $200.00 $866.66 $106.00 $459.33 31/08/2005 NEW
    > $210.00 $909.99 $138.00 $598.00 31/08/2005 OLD
    > $200.00 $866.66 $167.00 $723.66 31/08/2005 BEST
    >
    > Can someone help with development of the formula?
    >
    > Thanks in advance.
    >
    > James




  3. #3
    Registered User
    Join Date
    05-25-2006
    Posts
    10

    SUMIF in a SUMIF

    Hi,
    I have a similar doubt, but I couldn't understand the solution.
    Let’s take the same example:

    A B C
    1 Rent/Mth Start Date Type
    2 $459.33 31/08/2005 NEW
    3 $598.00 31/08/2005 OLD
    6 $723.66 31/08/2005 BEST
    5 ....
    6 .... dd/mm/yyyy

    So, to get a sum of column B when cell of column C="NEW" and when cell of column B<B6, I tried to use the formula:

    =SUMIF(C:C,C1,SUMIF(B:B,B6,A:A))

    Unfortunately, it doesn't work.
    How can I get this sum without an Auxiliary Column?
    Tks,

  4. #4
    Arvi Laanemets
    Guest

    Re: SUMIF/SUMPRODUCT/IF - 2 criteria - Date and Text

    Hi

    =SUMPRODUCT(--(C2:C10000="NEW"),--(B2:B10000<=$B$6),A2:A10000)
    (adjust ranges to real ones)

    NB! SUMPRODUCT doesn't support whole-column references. And multiplied
    ranges must be of same dimension (same number of rows/columns).

    How this works. For every element group, all elements are multiplied, and
    results are summed. With your data, are calculated values
    (--(C2="NEW"))*(--(B2<=B6))*A2
    (--(C3="NEW"))*(--(B3<=B6))*A3
    (--(C4="NEW"))*(--(B4<=B6))*A4
    ....

    Now, both equations in formula can be true or false. An unary transformation
    (--) converts TRUE/FALSE to their numeric equivalent, which is 0 for False
    and 1 for TRUE
    So summed are results of calculations like
    0*0*Value
    1*0*Value
    0*1*Value
    1*1*Value

    I.e. summed are values from rows, where both conditions were TRUE


    Arvi Laanemets



    "Sabine" <[email protected]> wrote in
    message news:[email protected]...
    >
    > Hi,
    > I have a similar doubt, but I couldn't understand the solution.
    > Let's take the same example:
    >
    > A B C
    > 1 Rent/Mth Start Date Type
    > 2 $459.33 31/08/2005 NEW
    > 3 $598.00 31/08/2005 OLD
    > 6 $723.66 31/08/2005 BEST
    > 5 ....
    > 6 .... dd/mm/yyyy
    >
    > So, to get a sum of column B when cell of column C="NEW" and when cell
    > of column B<B6, I tried to use the formula:
    >
    > =SUMIF(C:C,C1,SUMIF(B:B,B6,A:A))
    >
    > Unfortunately, it doesn't work.
    > How can I get this sum without an Auxiliary Column?
    > Tks,
    >
    >
    > --
    > Sabine
    > ------------------------------------------------------------------------
    > Sabine's Profile:

    http://www.excelforum.com/member.php...o&userid=34800
    > View this thread: http://www.excelforum.com/showthread...hreadid=545381
    >




  5. #5
    Registered User
    Join Date
    05-25-2006
    Posts
    10

    Thumbs up

    It works !!!!
    Tks a lot :-)

+ 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