+ Reply to Thread
Results 1 to 10 of 10

SUMPRODUCT across multiple sheets

  1. #1
    Registered User
    Join Date
    01-21-2011
    Location
    London
    MS-Off Ver
    Excel 2003
    Posts
    4

    SUMPRODUCT across multiple sheets

    In a workbook, I have a sheet called Start and another called Stop, and a variable number of sheet between them. The structure of all sheets is the same.

    I want to achieve this:
    SUMPRODUCT(Start:Stop!Q8,Start:Stop!Q34)
    (if it worked, that is)

    But this doesn't work. Please help!

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

    Re: SUMPRODUCT across multiple sheets

    excelnoob007, welcome to the board, please note however:

    Your post does not comply with Rule 8 of our Forum RULES.

    Cross-posting is when you post the same question in other forums on the web.

    You'll find people are disinclined to respond to cross-posts because they may be wasting their time solving a problem that has been solved elsewhere.
    We prefer that you not cross-post at all, but if you do (and it's unlikely to go unnoticed), you MUST provide a link (copy the url from the address bar in your browser) to the cross-posts.

    Read this to understand why we ask you to do this


    Note: the same principle holds true on other forums like MrExcel for example

  3. #3
    Forum Guru TMS's Avatar
    Join Date
    07-15-2010
    Location
    The Great City of Manchester, NW England ;-)
    MS-Off Ver
    MSO 2007,2010,365
    Posts
    44,428

    Re: SUMPRODUCT across multiple sheets

    I don't think you need SUMPRODUCT if it's just a 3-D SUM.

    Try:

    =SUM(Start:Stop!Q8:Q34)

    Regards
    Trevor Shuttleworth - Retired Excel/VBA Consultant

    I dream of a better world where chickens can cross the road without having their motives questioned

    'Being unapologetic means never having to say you're sorry' John Cooper Clarke


  4. #4
    Registered User
    Join Date
    01-21-2011
    Location
    London
    MS-Off Ver
    Excel 2003
    Posts
    4

  5. #5
    Registered User
    Join Date
    01-21-2011
    Location
    London
    MS-Off Ver
    Excel 2003
    Posts
    4

    Re: SUMPRODUCT across multiple sheets

    Quote Originally Posted by TMShucks View Post
    I don't think you need SUMPRODUCT if it's just a 3-D SUM.

    Try:
    =SUM(Start:Stop!Q8:Q34)
    Sorry, if I wasn't clear. I'm after sumproduct. Something like this:

    = Start!Q8*Start!Q34 + Sheet2!Q8*Sheet2!Q34 + Sheet3!Q8*Sheet3!Q34 +...Stop!Q8*Stop!Q34

  6. #6
    Forum Guru TMS's Avatar
    Join Date
    07-15-2010
    Location
    The Great City of Manchester, NW England ;-)
    MS-Off Ver
    MSO 2007,2010,365
    Posts
    44,428

    Re: SUMPRODUCT across multiple sheets

    Best I can suggest, in the absence of a more aesthetically pleasing solution, is to use a helper cell on each worksheet, say Q1. Then use the 3-D sum as previously suggested; in this case:

    =SUM(Start:Stop!Q1)

    The helper cell could have a white font colour so it's not obvious it's there.

    Regards

  7. #7
    Forum Guru TMS's Avatar
    Join Date
    07-15-2010
    Location
    The Great City of Manchester, NW England ;-)
    MS-Off Ver
    MSO 2007,2010,365
    Posts
    44,428

    Re: SUMPRODUCT across multiple sheets

    Sorry, I should have said, the helper cell would have the formula: =Q8*Q34

    Regards

  8. #8
    Forum Expert JBeaucaire's Avatar
    Join Date
    03-21-2004
    Location
    Bakersfield, CA
    MS-Off Ver
    2010, 2016, Office 365
    Posts
    33,492

    Re: SUMPRODUCT across multiple sheets

    The START/STOP trick isn't going to help you on this one. The easiest way to do this is to list the sheet names you want to sum3d in a range somewhere. I've done it in H1:H3 of the current sheet. Then this formula will do it:

    =SUMPRODUCT(N(INDIRECT("'"&$H$1:$H$3&"'!Q8")), N(INDIRECT("'"&$H$1:$H$3&"'!Q34")))


    You could also list the sheetnames elsewhere in named ranges, perhaps calling it MySheets, then the formula would look like:
    =SUMPRODUCT(N(INDIRECT("'"&MySheets&"'!Q8")), N(INDIRECT("'"&MySheets&"'!Q34")))
    _________________
    Microsoft MVP 2010 - Excel
    Visit: Jerry Beaucaire's Excel Files & Macros

    If you've been given good help, use the icon below to give reputation feedback, it is appreciated.
    Always put your code between code tags. [CODE] your code here [/CODE]

    ?None of us is as good as all of us? - Ray Kroc
    ?Actually, I *am* a rocket scientist.? - JB (little ones count!)

  9. #9
    Registered User
    Join Date
    07-17-2015
    Location
    London. England
    MS-Off Ver
    Excel 2013
    Posts
    3

    Re: SUMPRODUCT across multiple sheets

    Thanks JBeaucaire, very clever.

    In my sheets columns B and C have Qty and UnitPrice. My summary sheet has the total Qty in B3, and I have used your method in C3 to find the average Unit Price for the year:

    =SUMPRODUCT(N(INDIRECT("'"&Months&"'!B3")), N(INDIRECT("'"&Months&"'!C3")))/B3

    My next problem is how to replicate this formula down column C for all products. When dragged the row number does not increment - how do I do that?

  10. #10
    Forum Guru TMS's Avatar
    Join Date
    07-15-2010
    Location
    The Great City of Manchester, NW England ;-)
    MS-Off Ver
    MSO 2007,2010,365
    Posts
    44,428

    Re: SUMPRODUCT across multiple sheets

    @BG23: Welcome to the forum.

    Unfortunately your post does not comply with Rule 2 of our Forum RULES. Do not post a question in the thread of another member -- start your own thread.

    If you feel an existing thread is particularly relevant to your need, provide a link to the other thread in your new thread.

    Old threads are often only monitored by the original participants. New threads not only open you up to all possible participants again, they typically get faster response, too.

+ 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