+ Reply to Thread
Results 1 to 18 of 18

Sum multi worksheets for same criteria

  1. #1
    Registered User
    Join Date
    10-25-2011
    Location
    Hong Kong
    MS-Off Ver
    Excel 2010
    Posts
    28

    Sum multi worksheets for same criteria

    To sum up items with same criteria from various worksheets, a summary worksheet is created.
    Please advise if the sumproduct, sumifs, or any other functions can be put in the summary to make up the sum calculations.
    Attached is the sample excel for reference.

    Thanks in advance.
    Attached Files Attached Files

  2. #2
    Forum Expert Pepe Le Mokko's Avatar
    Join Date
    05-14-2009
    Location
    Belgium
    MS-Off Ver
    O365 v 2402
    Posts
    13,445

    Re: Sum multi worksheets for same criteria

    You can find explanations and examples of 3D references here

  3. #3
    Forum Expert
    Join Date
    07-20-2011
    Location
    Mysore, India.
    MS-Off Ver
    Excel 2019
    Posts
    8,577

    Re: Sum multi worksheets for same criteria

    UDF (User Defined Function)is the best solution.
    Code for UDF
    Please Login or Register  to view this content.
    How to Use UDF code:
    In Tthe developer tab click--> Visual Basic
    VB window opens
    Insert--> Module
    Paste the code.
    Close the window.
    Now UDF is available in Function List
    Attached Files Attached Files
    Pl note
    Array formula should be confirmed with Ctrl+Shift+Enter keys together.
    If answere is satisfactory press * to add reputation.

  4. #4
    Registered User
    Join Date
    10-25-2011
    Location
    Hong Kong
    MS-Off Ver
    Excel 2010
    Posts
    28

    Re: Sum multi worksheets for same criteria

    Hi Pepe Le Mokko,

    Thanks for the references.
    It is good but it seems it is not able to deal with that some items are not located in the same cell address from different worksheets.
    Thanks anyway!
    Last edited by tywlam; 11-16-2020 at 11:40 PM.

  5. #5
    Registered User
    Join Date
    10-25-2011
    Location
    Hong Kong
    MS-Off Ver
    Excel 2010
    Posts
    28

    Re: Sum multi worksheets for same criteria

    Hi kvsrinivasamurthy,

    It is complicated to me but I will spend some time on tracking how it works.

    Thanks a lot!
    Last edited by tywlam; 11-16-2020 at 11:41 PM.

  6. #6
    Forum Expert
    Join Date
    07-20-2011
    Location
    Mysore, India.
    MS-Off Ver
    Excel 2019
    Posts
    8,577

    Re: Sum multi worksheets for same criteria

    If you have any problem pl upload file and point out where is the problem. I will try to help.

  7. #7
    Registered User
    Join Date
    10-25-2011
    Location
    Hong Kong
    MS-Off Ver
    Excel 2010
    Posts
    28

    Re: Sum multi worksheets for same criteria

    Quote Originally Posted by kvsrinivasamurthy View Post
    If you have any problem pl upload file and point out where is the problem. I will try to help.
    Thanks!

    Just wonder if other than UDF and Macro, any other functions can do the job in a less effective way! I am using company's desktop and it does not allow me to run the Marco and Developer as well.

  8. #8
    Forum Expert
    Join Date
    07-20-2011
    Location
    Mysore, India.
    MS-Off Ver
    Excel 2019
    Posts
    8,577

    Re: Sum multi worksheets for same criteria

    Pl see file. Helper table added
    When more sheets are added add sheet name in Column L.
    In A2 then copied across.
    Please Login or Register  to view this content.
    Attached Files Attached Files

  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
    43,984

    Re: Sum multi worksheets for same criteria

    tywlam... is it possible for all the column headers to be present on each sheet, in ANY order, even if there are no data below them?
    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

  10. #10
    Registered User
    Join Date
    10-25-2011
    Location
    Hong Kong
    MS-Off Ver
    Excel 2010
    Posts
    28

    Re: Sum multi worksheets for same criteria

    Quote Originally Posted by Glenn Kennedy View Post
    tywlam... is it possible for all the column headers to be present on each sheet, in ANY order, even if there are no data below them?
    The data sheets are auto-generated and no header is printed if no data is available. It requires additional manual input for all headers presented in all sheets.
    Anyway it is a good alternative. I will give it a try and contact you again if no better means are found under my conditions.

    Thanks a lot.

  11. #11
    Forum Expert
    Join Date
    07-20-2011
    Location
    Mysore, India.
    MS-Off Ver
    Excel 2019
    Posts
    8,577

    Re: Sum multi worksheets for same criteria

    Have you seen my previous post

  12. #12
    Registered User
    Join Date
    10-25-2011
    Location
    Hong Kong
    MS-Off Ver
    Excel 2010
    Posts
    28

    Re: Sum multi worksheets for same criteria

    Quote Originally Posted by kvsrinivasamurthy View Post
    Have you seen my previous post
    Just finished the cross checking. It's very great! It's wonderful! I finally got what I want!
    Thank you very much.

  13. #13
    Forum Expert
    Join Date
    07-20-2011
    Location
    Mysore, India.
    MS-Off Ver
    Excel 2019
    Posts
    8,577

    Re: Sum multi worksheets for same criteria

    Thanks for feed back.

  14. #14
    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
    43,984

    Re: Sum multi worksheets for same criteria

    OK. Here is an alternative that is much easier to maintain. Create a Named Range (I called it "Sheets", CTRL-F3 to view/edit), using this formula:

    =$L$1:INDEX($L:$L,MATCH("zzz",$L:$L))

    as you add additional sheets to the list from L4 downwards, the Named range will not need to be changed again. Then, this array formula in B2, copied across and dnown will deliver the answer:

    =SUM(SUMIF(INDIRECT("'"&Sheets&"'!A1:J100"),$A2,OFFSET(INDIRECT("'"&Sheets&"'!A1:J100"),,MMULT(IF(T(OFFSET(INDIRECT("'"&Sheets&"'!A1:J1"),,COLUMN(INDIRECT("A:J"))-COLUMN(INDIRECT("A:A")),,1))=B$1,COLUMN(INDIRECT("A:J"))-COLUMN(INDIRECT("A:A")),0),TRANSPOSE(COLUMN(INDIRECT("A:J"))^0)),,1)))

    Array Formulae 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 curly brackets { } - or "curly braces" for those of you in the USA, or "flower brackets" for those of you in India - 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...

    I have set it to cover columns A to J, down as far as row 100. If you need more, adjust the bits in red in B2, array enter, and copy across & down. Do not use whole column references with INDIRECT, as it will process 1,000,000 rows. Make it reasonable, but not excessive!!
    Attached Files Attached Files

  15. #15
    Registered User
    Join Date
    10-25-2011
    Location
    Hong Kong
    MS-Off Ver
    Excel 2010
    Posts
    28

    Re: Sum multi worksheets for same criteria

    Quote Originally Posted by Glenn Kennedy View Post
    OK. Here is an alternative that is much easier to maintain.
    It seems this should use less resource to do the calculations. Let me try and come back to you later.
    Thanks again.
    Last edited by Glenn Kennedy; 11-18-2020 at 04:43 AM. Reason: Please don't clutter up the thread with unnecessary text.

  16. #16
    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
    43,984

    Re: Sum multi worksheets for same criteria

    On second thoughts, some of the INDIRECTS can be removed:

    =SUM(SUMIF(INDIRECT("'"&Sheets&"'!A1:J100"),$A2,OFFSET(INDIRECT("'"&Sheets&"'!A1:J100"),,MMULT(IF(T(OFFSET(INDIRECT("'"&Sheets&"'!A1:J1"),,COLUMN($A:$J)-COLUMN($A:$A),,1))=B$1,COLUMN($A:$J)-COLUMN($A:$A),0),TRANSPOSE(COLUMN($A:$J)^0)),,1)))

    This will reduce recalculation time.

  17. #17
    Registered User
    Join Date
    10-25-2011
    Location
    Hong Kong
    MS-Off Ver
    Excel 2010
    Posts
    28

    Re: Sum multi worksheets for same criteria

    This is good. It produces the same results as I expect.
    Thanks a lot!

  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
    43,984

    Re: Sum multi worksheets for same criteria

    You're welcome.



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

    It'd also be appreciated if you were to click the Add Reputation button at the foot of any of the posts of all members who helped you reach a solution.

+ 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. [SOLVED] Regular formula or array for multi colum multi criteria?
    By scaffdog845 in forum Excel Formulas & Functions
    Replies: 6
    Last Post: 03-25-2016, 01:40 PM
  2. New & Lost: Multi Criteria & Multi Row INDEX, SMALL, MATCH...
    By morleyp in forum Excel Formulas & Functions
    Replies: 0
    Last Post: 05-23-2014, 12:40 PM
  3. Large multi criteria / Vlookup/Choose Multi criteria
    By deanusa in forum Excel Formulas & Functions
    Replies: 1
    Last Post: 03-20-2014, 01:48 AM
  4. SUMIFS for Multi set of colums & multi criteria
    By Harish Kumar M in forum Excel Programming / VBA / Macros
    Replies: 4
    Last Post: 01-02-2014, 10:11 PM
  5. Count it multi criteria accross multi cells
    By jfoley5197 in forum Excel Formulas & Functions
    Replies: 3
    Last Post: 06-10-2013, 03:42 PM
  6. Replies: 9
    Last Post: 01-17-2013, 12:07 PM
  7. Sum with Multi Criteria in Multi Column
    By markuss in forum Excel Formulas & Functions
    Replies: 7
    Last Post: 03-01-2010, 05:35 PM

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