+ Reply to Thread
Results 1 to 20 of 20

Sum top 'n' numbers from across multiple sheets

  1. #1
    Registered User
    Join Date
    11-27-2023
    Location
    Australia
    MS-Off Ver
    Microsoft 365
    Posts
    9

    Question Sum top 'n' numbers from across multiple sheets

    Hi all, I'm trying to calculate the top 10 numbers from across 3 sheets.
    I have the following formula on one of my sheets but it's only calculating the top 10 of that sheet in the cell range. I want to get the top ten from across the sheets (not the top 10 in each sheet)...is this possible? If it helps, the range would be the same across all three sheets - W3:W27.
    Current formula: =SUM(LARGE(W3:W27,{1,2,3,4,5,6,7,8,9,10}))

  2. #2
    Forum Moderator AliGW's Avatar
    Join Date
    08-10-2013
    Location
    Retired in Ipswich, Suffolk, but grew up in Sawley, Derbyshire (England)
    MS-Off Ver
    MS 365 Subscription Insider Beta Channel v. 2404 (Windows 11 22H2 64-bit)
    Posts
    80,929

    Re: Sum top 'n' numbers from across multiple sheets

    Welcome to the forum.

    Try this:

    =SUM(BYCOL(HSTACK(Sheet1:Sheet3!W3:W27),LAMBDA(c,SUM(LARGE(c,{1,2,3,4,5,6,7,8,9,10})))))
    Attached Files Attached Files
    Last edited by AliGW; 11-27-2023 at 06:53 AM. Reason: Workbook added.
    Ali


    Enthusiastic self-taught user of MS Excel who's always learning!
    Don't forget to say "thank you" in your thread to anyone who has offered you help.
    You can reward them by clicking on * Add Reputation below their user name on the left, if you wish.

    Forum Rules (updated August 2023): please read them here.

  3. #3
    Forum Guru HansDouwe's Avatar
    Join Date
    06-21-2022
    Location
    Nederland
    MS-Off Ver
    365 V2403 (Build 17330.20000)
    Posts
    6,435

    Re: Sum top 'n' numbers from across multiple sheets

    Sum top 10 across the worksheets, please try:
    Formula: copy to clipboard
    Please Login or Register  to view this content.
    Attached Files Attached Files

  4. #4
    Forum Moderator AliGW's Avatar
    Join Date
    08-10-2013
    Location
    Retired in Ipswich, Suffolk, but grew up in Sawley, Derbyshire (England)
    MS-Off Ver
    MS 365 Subscription Insider Beta Channel v. 2404 (Windows 11 22H2 64-bit)
    Posts
    80,929

    Re: Sum top 'n' numbers from across multiple sheets

    Ah! I misread the opening post - this, then:

    =SUM(LARGE(VSTACK(Sheet1:Sheet3!A1:A26),{1,2,3,4,5,6,7,8,9,10}))
    Attached Files Attached Files

  5. #5
    Registered User
    Join Date
    11-27-2023
    Location
    Australia
    MS-Off Ver
    Microsoft 365
    Posts
    9

    Re: Sum top 'n' numbers from across multiple sheets

    Thank you for this, I have tried this and cannot seem to get it to work as a valid formula.

  6. #6
    Registered User
    Join Date
    11-27-2023
    Location
    Australia
    MS-Off Ver
    Microsoft 365
    Posts
    9

    Re: Sum top 'n' numbers from across multiple sheets

    Thank you very much for this reply.
    I have tried this and not had any luck.

    I get the below error:
    Attachment 850925

  7. #7
    Registered User
    Join Date
    11-27-2023
    Location
    Australia
    MS-Off Ver
    Microsoft 365
    Posts
    9

    Re: Sum top 'n' numbers from across multiple sheets

    Quote Originally Posted by HansDouwe View Post
    Sum top 10 across the worksheets, please try:
    Formula: copy to clipboard
    Please Login or Register  to view this content.
    Thank you very much for this.
    I have tried and not had any luck. I get the below error:
    Attachment 850926

  8. #8
    Forum Guru HansDouwe's Avatar
    Join Date
    06-21-2022
    Location
    Nederland
    MS-Off Ver
    365 V2403 (Build 17330.20000)
    Posts
    6,435

    Re: Sum top 'n' numbers from across multiple sheets

    I get the message "Invalid attachment specified".

    Please add an attachment via Go Advanced and Manage Attachments.

  9. #9
    Registered User
    Join Date
    11-27-2023
    Location
    Australia
    MS-Off Ver
    Microsoft 365
    Posts
    9

    Re: Sum top 'n' numbers from across multiple sheets

    Quote Originally Posted by HansDouwe View Post
    Sum top 10 across the worksheets, please try:
    Formula: copy to clipboard
    Please Login or Register  to view this content.
    Quote Originally Posted by HansDouwe View Post
    I get the message "Invalid attachment specified".

    Please add an attachment via Go Advanced and Manage Attachments.
    Thank you for this advice. Does this work now?
    Spreadsheet.PNG

  10. #10
    Forum Expert
    Join Date
    04-14-2009
    Location
    Taiwan
    MS-Off Ver
    Excel 2016,2019,O365
    Posts
    2,005

    Re: Sum top 'n' numbers from across multiple sheets

    Change Circuit 1:Mobility Aid to 'Circuit 1':'Mobility Aid'

  11. #11
    Forum Moderator AliGW's Avatar
    Join Date
    08-10-2013
    Location
    Retired in Ipswich, Suffolk, but grew up in Sawley, Derbyshire (England)
    MS-Off Ver
    MS 365 Subscription Insider Beta Channel v. 2404 (Windows 11 22H2 64-bit)
    Posts
    80,929

    Re: Sum top 'n' numbers from across multiple sheets

    You need to change the sheet references. Something like this:

    =SUM(TAKE(SORT(TOCOL(HSTACK('Circuit 1:Mobility Aid'!A1:A26))),-10))

    If you can't get it to work, attach a sample workbook, NOT a picture.

  12. #12
    Forum Guru HansDouwe's Avatar
    Join Date
    06-21-2022
    Location
    Nederland
    MS-Off Ver
    365 V2403 (Build 17330.20000)
    Posts
    6,435

    Re: Sum top 'n' numbers from across multiple sheets

    If there are spaces in the sheet names you need quotes.

    Please try ....HSTACK('Circuit 1:Mobility Aid'!W3:W27)....

    If there still an error remains, please upload a sample workbook.

  13. #13
    Forum Moderator AliGW's Avatar
    Join Date
    08-10-2013
    Location
    Retired in Ipswich, Suffolk, but grew up in Sawley, Derbyshire (England)
    MS-Off Ver
    MS 365 Subscription Insider Beta Channel v. 2404 (Windows 11 22H2 64-bit)
    Posts
    80,929

    Re: Sum top 'n' numbers from across multiple sheets

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

    Also, if you have not already done so, you may not be aware that you can thank anyone who offered you help towards a solution for your issue by clicking the small star icon (* Add Reputation) located in the lower left corner of the post in which the help was given. By doing so you can add to the reputation(s) of each of those who offered help.

  14. #14
    Registered User
    Join Date
    11-27-2023
    Location
    Australia
    MS-Off Ver
    Microsoft 365
    Posts
    9

    Re: Sum top 'n' numbers from across multiple sheets

    Quote Originally Posted by windknife View Post
    Change Circuit 1:Mobility Aid to 'Circuit 1':'Mobility Aid'
    Thank you.

  15. #15
    Registered User
    Join Date
    11-27-2023
    Location
    Australia
    MS-Off Ver
    Microsoft 365
    Posts
    9

    Re: Sum top 'n' numbers from across multiple sheets

    Quote Originally Posted by AliGW View Post
    You need to change the sheet references. Something like this:

    =SUM(TAKE(SORT(TOCOL(HSTACK('Circuit 1:Mobility Aid'!A1:A26))),-10))

    If you can't get it to work, attach a sample workbook, NOT a picture.
    Thank you very much for your help - it worked!

  16. #16
    Forum Expert
    Join Date
    04-14-2009
    Location
    Taiwan
    MS-Off Ver
    Excel 2016,2019,O365
    Posts
    2,005

    Re: Sum top 'n' numbers from across multiple sheets

    You are welcome.
    -----------------------------------
    If that takes care of your original question, please click on "Thread Tools" from the menu link above and mark this thread as SOLVED.

  17. #17
    Registered User
    Join Date
    11-27-2023
    Location
    Australia
    MS-Off Ver
    Microsoft 365
    Posts
    9

    Re: Sum top 'n' numbers from across multiple sheets

    Quote Originally Posted by AliGW View Post
    You need to change the sheet references. Something like this:

    =SUM(TAKE(SORT(TOCOL(HSTACK('Circuit 1:Mobility Aid'!A1:A26))),-10))

    If you can't get it to work, attach a sample workbook, NOT a picture.
    Thank you - this worked! Appreciate your help.

  18. #18
    Registered User
    Join Date
    11-27-2023
    Location
    Australia
    MS-Off Ver
    Microsoft 365
    Posts
    9

    Re: Sum top 'n' numbers from across multiple sheets

    Quote Originally Posted by HansDouwe View Post
    If there are spaces in the sheet names you need quotes.

    Please try ....HSTACK('Circuit 1:Mobility Aid'!W3:W27)....

    If there still an error remains, please upload a sample workbook.
    Thank you very much!

  19. #19
    Forum Guru HansDouwe's Avatar
    Join Date
    06-21-2022
    Location
    Nederland
    MS-Off Ver
    365 V2403 (Build 17330.20000)
    Posts
    6,435

    Re: Sum top 'n' numbers from across multiple sheets

    You are Welcome!

    Thanks for the feedback and rep. Glad to have helped. .

  20. #20
    Forum Moderator AliGW's Avatar
    Join Date
    08-10-2013
    Location
    Retired in Ipswich, Suffolk, but grew up in Sawley, Derbyshire (England)
    MS-Off Ver
    MS 365 Subscription Insider Beta Channel v. 2404 (Windows 11 22H2 64-bit)
    Posts
    80,929

    Re: Sum top 'n' numbers from across multiple sheets

    Glad to have helped.

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

+ 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. How to insert numbers in multiple sheets
    By joleeee in forum Excel Programming / VBA / Macros
    Replies: 1
    Last Post: 03-03-2021, 09:26 PM
  2. [SOLVED] Prevent Duplicate ID Numbers on Multiple Sheets
    By crazyforexcel in forum Excel General
    Replies: 12
    Last Post: 02-06-2020, 06:26 PM
  3. [SOLVED] finding missing numbers in multiple excel sheets
    By kswapnadevi in forum Excel Programming / VBA / Macros
    Replies: 10
    Last Post: 05-31-2018, 01:23 AM
  4. Replies: 1
    Last Post: 01-20-2014, 03:33 PM
  5. Finding Duplicate Serial Numbers in multiple sheets
    By leeaw in forum Excel Programming / VBA / Macros
    Replies: 2
    Last Post: 01-22-2013, 12:33 AM
  6. Multiple excel sheets into one with different cell numbers
    By scubadivingfool in forum Excel General
    Replies: 3
    Last Post: 05-10-2012, 10:03 AM
  7. Page numbers over multiple sheets
    By neilpateluk in forum Excel General
    Replies: 0
    Last Post: 01-29-2009, 08:50 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