Results 1 to 8 of 8

Thread: Summing Data based on certain criteria

  1. #1
    Senior Member
    Join Date
    Apr 2012
    Posts
    193
    Rep Power
    13

    Summing Data based on certain criteria

    I would like to add the data highlighted in Col A, which I have named "other_Income". The values applicable to these items are in Columns F, I & J

    I have used the sum function to show you what the answer should be. Could one use a range name and then an offset function to add the values based on the criteria or use sumifs?

    It would be appreciated if you could assist me with a formula to add a series of data based on crieria such as this.
    Attached Files Attached Files
    Last edited by Rick Rothstein; 01-28-2013 at 09:59 PM.

  2. #2
    Forum Guru Rick Rothstein's Avatar
    Join Date
    Feb 2012
    Posts
    662
    Rep Power
    13
    Create a new Defined Name that consist of the entire rows of 3:5,7,11:12 and name it OI (short for Other Income), then try this formula (those single spaces between OI and the column designations are on purpose)...

    =SUM(OI F:F,OI I:I,OI J:J)

  3. #3
    Senior Member
    Join Date
    Apr 2012
    Posts
    193
    Rep Power
    13
    Quote Originally Posted by Rick Rothstein View Post
    Create a new Defined Name that consist of the entire rows of 3:5,7,11:12 and name it OI (short for Other Income), then try this formula (those single spaces between OI and the column designations are on purpose)...

    =SUM(OI F:F,OI I:I,OI J:J)
    Hi Rick

    Thanks for the help, much appreciated. First time I've come accross this formula-very clever

    Regards

    Howard

  4. #4
    Forum Guru Rick Rothstein's Avatar
    Join Date
    Feb 2012
    Posts
    662
    Rep Power
    13
    Quote Originally Posted by Howardc View Post
    Hi Rick

    Thanks for the help, much appreciated. First time I've come accross this formula-very clever
    Two ranges separated by a single space returns the intersection of the two ranges. And, now that I think of it some more, we can take advantage of the fact that Columns I and J are contiguous and shorten the formula to this...

    =SUM(OI F:F,OI I:J)

    And, of course, instead of using my OI defined name, you can simply change your Other_Income defined name to be the entire rows and use that in place of my OI if you are not using Other_Income anywhere else in your workbook.
    Last edited by Rick Rothstein; 01-28-2013 at 10:17 PM.

  5. #5
    Administrator Admin's Avatar
    Join Date
    Mar 2011
    Posts
    1,123
    Rep Power
    10
    Hi

    You could try this Array formula.

    =SUM(IF(ISNUMBER(MATCH(A3:A13&"",A20:A25&"",0)),IF (ISNUMBER(MATCH(F1:J1,B20:B22,0)),F3:J13)))

    where

    A20:A25 - Other income criteria,
    B20:B22 - the months
    Cheers !

    Excel Range to BBCode Table
    Use Social Networking Tools If You Like the Answers !

    Message to Cross Posters

    @ Home - Office 2010/2013/2016 on Win 10 (64 bit); @ Work - Office 2016 on Win 10 (64 bit)

  6. #6
    Administrator Admin's Avatar
    Join Date
    Mar 2011
    Posts
    1,123
    Rep Power
    10
    Quote Originally Posted by Rick Rothstein View Post
    Two ranges separated by a single space returns the intersection of the two ranges. And, now that I think of it some more, we can take advantage of the fact that Columns I and J are contiguous and shorten the formula to this...

    =SUM(OI F:F,OI I:J)

    And, of course, instead of using my OI defined name, you can simply change your Other_Income defined name to be the entire rows and use that in place of my OI if you are not using Other_Income anywhere else in your workbook.
    Wow ! nice one Rick, I have never seen this before.
    Cheers !

    Excel Range to BBCode Table
    Use Social Networking Tools If You Like the Answers !

    Message to Cross Posters

    @ Home - Office 2010/2013/2016 on Win 10 (64 bit); @ Work - Office 2016 on Win 10 (64 bit)

  7. #7
    Senior Member
    Join Date
    Apr 2012
    Posts
    193
    Rep Power
    13
    Hi Guys

    Thanks for the help and explanations, much appreciated

  8. #8
    Junior Member
    Join Date
    Sep 2011
    Posts
    8
    Rep Power
    0
    great trick

Similar Threads

  1. Replies: 4
    Last Post: 05-05-2013, 04:01 AM
  2. Split data based on criteria
    By Mahesh.sreekakulam in forum Excel Help
    Replies: 3
    Last Post: 06-08-2012, 09:30 PM
  3. Replies: 7
    Last Post: 03-06-2012, 07:49 AM
  4. Lookup Based on Criteria
    By maruthi in forum Excel Help
    Replies: 2
    Last Post: 02-15-2012, 08:49 AM
  5. Find Value Based On Criteria
    By excel_learner in forum Excel Help
    Replies: 10
    Last Post: 07-30-2011, 10:27 AM

Posting Permissions

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