+ Reply to Thread
Results 1 to 19 of 19

How to add multiple columns based on criteria in rows

  1. #1
    Registered User
    Join Date
    04-05-2017
    Location
    Malta
    MS-Off Ver
    Excel 2010
    Posts
    24

    How to add multiple columns based on criteria in rows

    Hi All,

    I'm trying to add figures in multiple rows based on multiple conditions at row level.


    I did include an attachment cuase that is the easiest way to understand my issue. I know how to do this using indirect but my boss hates any file that has indirect in it!!!!

    Many thanks inadvance
    Attached Files Attached Files

  2. #2
    Forum Moderator Glenn Kennedy's Avatar
    Join Date
    07-08-2012
    Location
    Digital Nomad... occasionally based in Ireland.
    MS-Off Ver
    O365 (PC) V 2403
    Posts
    44,053

    Re: How to add multiple columns based on criteria in rows

    One way:

    =SUM((INDEX(INDEX($E$7:$N$11,MATCH(1,INDEX(($B$7:$B$11=$E$16)*($C$7:$C$11=$E$17)*($D$7:$D$11=$E$18),0),0),),MATCH(E14,$E$6:$N$6,0))):(INDEX(INDEX($E$7:$N$11,MATCH(1,INDEX(($B$7:$B$11=$E$16)*($C$7:$C$11=$E$17)*($D$7:$D$11=$E$18),0),0),),MATCH(E15,$E$6:$N$6,0))))
    Attached Files Attached Files
    Glenn




    None of us get paid for helping you... we do this for fun. So DON'T FORGET to say "Thank You" to all who have freely given some of their time to help YOU.

    Temporary addition of accented to illustrate ongoing problem to the TT: L? fh?ile P?draig sona dhaoibh

  3. #3
    Forum Moderator Glenn Kennedy's Avatar
    Join Date
    07-08-2012
    Location
    Digital Nomad... occasionally based in Ireland.
    MS-Off Ver
    O365 (PC) V 2403
    Posts
    44,053

    Re: How to add multiple columns based on criteria in rows

    You sent me a PM asking for an explanation. Well, here it is... Your formula in your sheet was:

    =SUM((INDEX($E$7:$N$7,MATCH(E14,$E$6:$N$6,FALSE)))INDEX($E$7:$N$7,MATCH(E15,$E$6:$N$6,FALSE))))

    The fist thing I did was move part of it down (the bits in red) to refer to the correct row (just so that I would know when i was going to get teh right answer. it then looked like:


    =SUM((INDEX($E$9:$N$9,MATCH(E14,$E$6:$N$6,FALSE)))INDEX($E$9:$N$9,MATCH(E15,$E$6:$N$6,FALSE))))

    So you formula, at its most basic used two index Matches to do =SUM(from here - to here)

    Next step, OK. How can I return that?

    =SUM((INDEX($E$9:$N$9,MATCH(E14,$E$6:$N$6,FALSE)))INDEX($E$9:$N$9,MATCH(E15,$E$6:$N$6,FALSE))))

    I decided to write a formual that would take the entire table and then use the criteria that you set. I came up with:

    =INDEX($E$7:$N$11,MATCH(1,($B$7:$B$11=$E$16)*($C$7:$C$11=$E$17)*($D$7:$D$11=$E$18),0),)

    This was looking at the entire range (red), and then (blue) looking at your 3 criteria in turn (muliplying them for criterion 1 AND criterion 2 AND criterion3). This returns and array of 1s for TRUE and 0s for false... ultimately only one 1.... matching the row in the array where all 3 criteria were met. That formula is an array formula. However, it is easy to coerce it into working as a non array formula by wraping it in an INDEX:

    =INDEX($E$7:$N$11,MATCH(1,INDEX(($B$7:$B$11=$E$16)*($C$7:$C$11=$E$17)*($D$7:$D$11=$E$18),0),0),)

    I then substituted that string into YOUR formula to replace the bits in red in the first formula at the top of this explanation. So, all I did was to build on what you had, by adding in a multi-criteria INDEX-MATCH to select teh correct row. It just looks horrendous!!

    So... you're welcome.



    It would be very nice if you were to just click the Add Reputation button at the foot of any of the posts of members who helped you reach a solution.

    Finally, if that takes care of your original question, please select "Thread Tools" from the menu link above and mark this thread as SOLVED.

  4. #4
    Forum Moderator Glenn Kennedy's Avatar
    Join Date
    07-08-2012
    Location
    Digital Nomad... occasionally based in Ireland.
    MS-Off Ver
    O365 (PC) V 2403
    Posts
    44,053

    Re: How to add multiple columns based on criteria in rows

    Posted again to get rid of the bl@@dy smilies!!!

    You sent me a PM asking for an explanation. Well, here it is... Your formula in your sheet was:

    =SUM((INDEX($E$7:$N$7,MATCH(E14,$E$6:$N$6,FALSE)))INDEX($E$7:$N$7,MATCH(E15,$E$6:$N$6,FALSE))))

    The fist thing I did was move part of it down (the bits in red) to refer to the correct row (just so that I would know when i was going to get teh right answer. it then looked like:


    =SUM((INDEX($E$9:$N$9,MATCH(E14,$E$6:$N$6,FALSE)))INDEX($E$9:$N$9,MATCH(E15,$E$6:$N$6,FALSE))))

    So you formula, at its most basic used two index Matches to do =SUM(from here - to here)

    Next step, OK. How can I return that?

    =SUM((INDEX($E$9:$N$9,MATCH(E14,$E$6:$N$6,FALSE)))INDEX($E$9:$N$9,MATCH(E15,$E$6:$N$6,FALSE))))

    I decided to write a formual that would take the entire table and then use the criteria that you set. I came up with:

    =INDEX($E$7:$N$11,MATCH(1,($B$7:$B$11=$E$16)*($C$7:$C$11=$E$17)*($D$7:$D$11=$E$18),0),)

    This was looking at the entire range (red), and then (blue) looking at your 3 criteria in turn (muliplying them for criterion 1 AND criterion 2 AND criterion3). This returns and array of 1s for TRUE and 0s for false... ultimately only one 1.... matching the row in the array where all 3 criteria were met. That formula is an array formula. However, it is easy to coerce it into working as a non array formula by wraping it in an INDEX:

    =INDEX($E$7:$N$11,MATCH(1,INDEX(($B$7:$B$11=$E$16)*($C$7:$C$11=$E$17)*($D$7:$D$11=$E$18),0),0),)

    I then substituted that string into YOUR formula to replace the bits in red in the first formula at the top of this explanation. So, all I did was to build on what you had, by adding in a multi-criteria INDEX-MATCH to select teh correct row. It just looks horrendous!!

    So... you're welcome.


    It would be very nice if you were to just click the Add Reputation button at the foot of any of the posts of members who helped you reach a solution.

    Finally, if that takes care of your original question, please select "Thread Tools" from the menu link above and mark this thread as SOLVED.

  5. #5
    Registered User
    Join Date
    04-05-2017
    Location
    Malta
    MS-Off Ver
    Excel 2010
    Posts
    24

    Re: How to add multiple columns based on criteria in rows

    Many thanks for your reply, much appreciated.

  6. #6
    Registered User
    Join Date
    12-01-2020
    Location
    singapore
    MS-Off Ver
    MS2016
    Posts
    35

    Re: How to add multiple columns based on criteria in rows

    E21

    =sumproduct((--mid(e6:n6,find("-",e6:n6)+1,99)>=--mid(e14,find("-",e14)+1,99))*(--mid(e6:n6,find("-",e6:n6)+1,99)<=--mid(e15,find("-",e15)+1,99))*(b7:b11=e16)*(c7:c11=e17)*(d7:d11=e18)*e7:n11)

  7. #7
    Registered User
    Join Date
    04-05-2017
    Location
    Malta
    MS-Off Ver
    Excel 2010
    Posts
    24

    Re: How to add multiple columns based on criteria in rows

    Hi Glenn,

    Was thinking this morning..... I think the formula would look 'less horrendous' if i were to concatenate the criteria and then base the search on the concatenated criteria.

    So i would need to change this

    =INDEX($E$7:$N$11,MATCH(1,INDEX(($B$7:$B$11=$E$16)*($C$7:$C$11=$E$17)*($D$7:$D$11=$E$18),0),0),)

    This would essential drop my criteria from 3 to 1. I tried to play around with the statment but im getting a #ref!

  8. #8
    Forum Moderator Glenn Kennedy's Avatar
    Join Date
    07-08-2012
    Location
    Digital Nomad... occasionally based in Ireland.
    MS-Off Ver
    O365 (PC) V 2403
    Posts
    44,053

    Re: How to add multiple columns based on criteria in rows

    Rather than clutter your sheet up, you could always use the repeated bit as a Named Range. I used this:

    =INDEX(Sheet2!$E$7:$N$11,MATCH(1,INDEX((Sheet2!$B$7:$B$11=Sheet2!$E$16)*(Sheet2!$C$7:$C$11=Sheet2!$E$17)*(Sheet2!$D$7:$D$11=Sheet2!$E$18),0),0),)

    to create a Named Range, called... wait for it.... Range.

    The formula in the sheet then becomes:

    Please Login or Register  to view this content.
    Attached Files Attached Files
    Last edited by alansidman; 01-23-2021 at 04:42 AM.

  9. #9
    Forum Moderator Glenn Kennedy's Avatar
    Join Date
    07-08-2012
    Location
    Digital Nomad... occasionally based in Ireland.
    MS-Off Ver
    O365 (PC) V 2403
    Posts
    44,053

    Re: How to add multiple columns based on criteria in rows

    That bloody smiley again!! I do not know how to disable it permanently!!!

  10. #10
    Forum Moderator alansidman's Avatar
    Join Date
    02-02-2010
    Location
    Steamboat Springs, CO
    MS-Off Ver
    MS Office 365 Version 2405 Win 11 Home 64 Bit
    Posts
    23,883

    Re: How to add multiple columns based on criteria in rows

    Glenn, I edited it by putting the formula inside of code tags. That seems to fix the problem that occurs when you have colon and a right or left parens next.
    Alan עַם יִשְׂרָאֵל חַי


    Change an Ugly Report with Power Query
    Database Normalization
    Complete Guide to Power Query
    Man's Mind Stretched to New Dimensions Never Returns to Its Original Form

  11. #11
    Forum Moderator Glenn Kennedy's Avatar
    Join Date
    07-08-2012
    Location
    Digital Nomad... occasionally based in Ireland.
    MS-Off Ver
    O365 (PC) V 2403
    Posts
    44,053

    Re: How to add multiple columns based on criteria in rows

    Thank you Alan! The is no carpet in the room I'm in. If there was, I'd be chewing it in rage!!

  12. #12
    Registered User
    Join Date
    04-05-2017
    Location
    Malta
    MS-Off Ver
    Excel 2010
    Posts
    24

    Re: How to add multiple columns based on criteria in rows

    Hi Glenn,

    Many thanks for that, amazing! My wife cannot understand why I am in front of a spreadsheet on a Saturday morning!

    I never knew that a range can actually be a formula.

    Some of my colleagues might freak out when they see a formula in a range. would you be able to guide me how to replace INDEX($E$7:$N$11,MATCH(1,INDEX(($B$7:$B$11=$E$16)*($C$7:$C$11=$E$17)*($D$7:$D$11=$E$18),0),0),)

    to use just one criterion instead of three. And one final question, in that statement, what is the function of the wildcard ?

  13. #13
    Forum Moderator Glenn Kennedy's Avatar
    Join Date
    07-08-2012
    Location
    Digital Nomad... occasionally based in Ireland.
    MS-Off Ver
    O365 (PC) V 2403
    Posts
    44,053

    Re: How to add multiple columns based on criteria in rows

    What wildcard?

  14. #14
    Registered User
    Join Date
    04-05-2017
    Location
    Malta
    MS-Off Ver
    Excel 2010
    Posts
    24

    Re: How to add multiple columns based on criteria in rows

    I thought that the * in the statement below is a wild card.
    INDEX($E$7:$N$11,MATCH(1,INDEX(($B$7:$B$11=$E$16)*($C$7:$C$11=$E$17)*($D$7:$D$11=$E$18),0),0),)

    And sorry to pester you but im super curious. : how can I change the above statement to just feed from one criteria?

  15. #15
    Forum Moderator Glenn Kennedy's Avatar
    Join Date
    07-08-2012
    Location
    Digital Nomad... occasionally based in Ireland.
    MS-Off Ver
    O365 (PC) V 2403
    Posts
    44,053

    Re: How to add multiple columns based on criteria in rows

    No it is a multiplication. Effectively requring an AND for each of the criteria.

    The price of what you wan tis an array formula.

    Formula: copy to clipboard
    Please Login or Register  to view this content.


    You seem to be using an older version of Excel than me. So, please refer to the attached file. If the formulae are enclosed within a pair of { }, these are array formulae.

    These are a little different from ordinary formulae in that they MUST be confirmed in the FIRST CELL ONLY by pressing CTRL+SHIFT+ENTER to activate the array, not just ENTER. After that, the array can be dragged down as normal, to cover the desired range.

    You will know the array is active when you see the curly brackets { } appear around the outside of your formula. If you do not use CTRL+SHIFT+ENTER you will (almost always) get an error message or an incorrect answer. Press F2 on that cell and try again.

    Don't type the curly brackets yourself - it won't work...

    if your colleagyues don't like Named Ranges (idiots) they will not like array formulae either. If you click on a cell with an array formula, it loses the array and needs CTRL-SHIFT-ENTER again.

    Go for the Range, or offer to buy them a piece of slate and a chisel instead of Excel... or an abacus...

  16. #16
    Registered User
    Join Date
    04-05-2017
    Location
    Malta
    MS-Off Ver
    Excel 2010
    Posts
    24

    Re: How to add multiple columns based on criteria in rows

    Hi there glenn,

    Again many thanks for your reply. I was reading online that it can be done with an array formula but i thought there must be a simpler way.... not a huge fan or array formulae to be honest. I will go with the first solution.

    many many thanks

  17. #17
    Forum Moderator Glenn Kennedy's Avatar
    Join Date
    07-08-2012
    Location
    Digital Nomad... occasionally based in Ireland.
    MS-Off Ver
    O365 (PC) V 2403
    Posts
    44,053

    Re: How to add multiple columns based on criteria in rows

    Neither am I. Users with five thumbs on each hand always knock them over... so I always tried to avoid them. Office 365 has done away with them, but has brought along a pile of new things i'm trying to learn!

    But Named ranges as SOOOO useful, as you will find. Indeed, I will make one further improvement. The NR should really be made dynamic, to adjust to the size of your data, automatically.

    i'll do that in a moment.

  18. #18
    Forum Moderator Glenn Kennedy's Avatar
    Join Date
    07-08-2012
    Location
    Digital Nomad... occasionally based in Ireland.
    MS-Off Ver
    O365 (PC) V 2403
    Posts
    44,053

    Re: How to add multiple columns based on criteria in rows

    In your real data...

    1. Are the criteria and the formula on the same sheet, or a different one?

    2. If on the same one, can I move the criteria and formulae?

    3. If on a different one, can it be guaranteed that there will be NOTHING below AND to the right of the raw data?

  19. #19
    Forum Moderator Glenn Kennedy's Avatar
    Join Date
    07-08-2012
    Location
    Digital Nomad... occasionally based in Ireland.
    MS-Off Ver
    O365 (PC) V 2403
    Posts
    44,053

    Re: How to add multiple columns based on criteria in rows

    No reply... your wife has dragged you away from the PC.

    Take a look at this. It will accept new rows (currently to 1000) and columns (up to column BZ), without you needing to make any change to the ranges in the formula. They ALL adjust automatically.

+ Reply to Thread

Thread Information

Users Browsing this Thread

There are currently 1 users browsing this thread. (0 members and 1 guests)

Similar Threads

  1. Replies: 1
    Last Post: 02-09-2017, 05:55 PM
  2. summing data based on criteria on multiple rows and columns
    By Andy N in forum Excel Formulas & Functions
    Replies: 2
    Last Post: 02-09-2017, 03:07 PM
  3. Sum values based on multiple criteria in rows and columns
    By mattadler22 in forum Excel Formulas & Functions
    Replies: 4
    Last Post: 07-20-2015, 03:09 AM
  4. [SOLVED] Sum if based on two criteria and values in multiple rows and columns
    By Alkina in forum Excel Formulas & Functions
    Replies: 3
    Last Post: 10-15-2013, 09:18 AM
  5. Pivot multiple columns into rows based on criteria
    By vboz5 in forum Excel Formulas & Functions
    Replies: 0
    Last Post: 08-09-2012, 11:54 AM
  6. Replies: 1
    Last Post: 05-18-2009, 11:21 AM
  7. Remove data based on criteria from multiple columns and rows
    By jvegastn in forum Excel Programming / VBA / Macros
    Replies: 4
    Last Post: 02-09-2009, 11:42 AM

Tags for this Thread

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