+ Reply to Thread
Results 1 to 9 of 9

Sum if function??

  1. #1
    Registered User
    Join Date
    02-16-2007
    Posts
    54

    Question Sum if function??

    Please refer to the attached doc:

    In sheet 3, column R (revenue hours) I need to report the following:

    Match B3 with “Timesheets” E:E and sum is the total hours in V:V where D:D equals 001 (there will be more than one line of 001 to sum up) or 006.
    Attached Files Attached Files

  2. #2
    Forum Expert martindwilson's Avatar
    Join Date
    06-23-2007
    Location
    London,England
    MS-Off Ver
    office 97 ,2007
    Posts
    19,320

    Re: Sum if function??

    =SUMPRODUCT((Timesheets!$$2:$E$20=B3)*(Timesheets!$D$2:$D$20="001")*(Timesheets!$V$2:$V$20))
    or using your named ranges
    =SUMPRODUCT((DATA5=B3)*(DATA4="001")*(DATA22))
    Last edited by martindwilson; 04-06-2009 at 05:32 AM.
    "Unless otherwise stated all my comments are directed at OP"

    Mojito connoisseur and now happily retired
    where does code go ?
    look here
    how to insert code

    how to enter array formula

    why use -- in sumproduct
    recommended reading
    wiki Mojito

    how to say no convincingly

    most important thing you need
    Martin Wilson: SPV
    and RSMBC

  3. #3
    Forum Guru DonkeyOte's Avatar
    Join Date
    10-22-2008
    Location
    Northumberland, UK
    MS-Off Ver
    O365
    Posts
    21,531

    Re: Sum if function??

    Some will suggest a Sumproduct

    Sheet3!R3
    =SUMPRODUCT(--(Timesheets!$E$2:$E$1000=$B3),--(Timesheets!$D$2:$D$1000="001"),Timesheets!$V$2:$V$1000)

    Given that you're running these in a matrix you will invariably end up with a lot of them and they are inefficient in terms of performance.

    Better to create a concatenation key on Timesheets and use non-Sumproduct/CSE Array formulae, eg:

    Timesheets!Y2: =D2&":"&E2
    copied down for all rows

    Sheet3!R3
    =SUMIF(Timesheets!$Y$2:$Y$1000,"001:"&$B3,Timesheets!$V$2:$V$1000)

    Not as elegant but a lot more efficient especially when used in large quantities.

  4. #4
    Registered User
    Join Date
    02-16-2007
    Posts
    54

    Question Re: Sum if function??

    Thanks very much, this is summing up 001 in "Timesheets" column D only, i need to sum up 001 and 006 (sorry not or), i'm flddling with the formuale to add it but with little joy ...

  5. #5
    Forum Expert martindwilson's Avatar
    Join Date
    06-23-2007
    Location
    London,England
    MS-Off Ver
    office 97 ,2007
    Posts
    19,320

    Re: Sum if function??

    =sumproduct((data5=b3)*(or(data4="001",(data4="006")))*(data22))
    but if you are always going to have only001 /006 rthen just use sumif on the name
    =SUMIF(DATA5,B3,DATA22)
    Last edited by martindwilson; 04-06-2009 at 05:47 AM.

  6. #6
    Forum Guru DonkeyOte's Avatar
    Join Date
    10-22-2008
    Location
    Northumberland, UK
    MS-Off Ver
    O365
    Posts
    21,531

    Re: Sum if function??

    To conduct an OR within a Sumproduct utilise the + operator (if you have numerous test you can switch to an ISNUMBER(MATCH test with an inline array of accepted values))

    Please Login or Register  to view this content.
    Given 001 + 006 can not exist in D simultaneously the above should work without incident.

    It would still be quicker to conduct 2 SUMIFs using Concatenation (IMO)

    Please Login or Register  to view this content.
    Last edited by DonkeyOte; 04-06-2009 at 05:49 AM.

  7. #7
    Forum Expert martindwilson's Avatar
    Join Date
    06-23-2007
    Location
    London,England
    MS-Off Ver
    office 97 ,2007
    Posts
    19,320

    Re: Sum if function??

    dk it doesnt make a lot of difference i just tried it with 5000 rows and couldnt see any lag in calculation!
    mind you why + ?
    (or(data4="001",(data4="006")) seems to work ok or am i missing something? or is it just a save on typing thing?
    Last edited by martindwilson; 04-06-2009 at 05:52 AM.

  8. #8
    Forum Guru DonkeyOte's Avatar
    Join Date
    10-22-2008
    Location
    Northumberland, UK
    MS-Off Ver
    O365
    Posts
    21,531

    Re: Sum if function??

    Quote Originally Posted by martindwilson View Post
    dk it doesnt make a lot of difference i just tried it with 5000 rows and couldnt see any lag in calculation!
    mind you why + ?
    (or(data4="001",(data4="006")) seems to work ok or am i missing something? or is it just a save on typing thing?
    I can tell you categorically that using Arrays / Sumproduct with large ranges used extensively will cripple calculation... the volume of calcs performed in these methods is vastly greater than using SUMIF/COUNTIF ... if you look around the board you will find countless examples of this... too many people (IMHO) advocate Arrays/Sumproducts when clearly the OP intends to use them in Volume... better to advise alternate approaches (be it Concatenation, Pivot Table etc etc...)

    Re: + Operator ... OR's in CSE / Sumproduct do not work like a traditional OR... if you check your results carefully you will find your formula does not work.

  9. #9
    Registered User
    Join Date
    02-16-2007
    Posts
    54

    Re: Sum if function??

    excellent, thankyou so much. Happy to close the thread!!

+ 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