+ Reply to Thread
Results 1 to 11 of 11

Sum with dynamic range

  1. #1
    Registered User
    Join Date
    12-03-2020
    Location
    Netherlands
    MS-Off Ver
    office 365 proplus
    Posts
    4

    Sum with dynamic range

    Hi, I need some help with a formula I can't seem to figure out. I have a dataset of sales by weeknumber and year. When I select the starting week+year and end week+year (from a dropdown menu), I want the sum to automatically adjust.
    I attached an example sheet. In yellow is what should be the outcome of the sum.
    Many thanks for your help!

    ATD
    Attached Files Attached Files
    Last edited by ATD09; 12-03-2020 at 10:08 AM.

  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,002

    Re: Sum with dynamic range

    One way:

    =SUM(INDEX(C$2:C$500,MATCH(1,INDEX(((E$2:E$500=H2)*(D$2:D$500=G2)),0),0)):INDEX(C$2:C$500,MATCH(1,INDEX(((E$2:E$500=H5)*(D$2:D$500=G5)),0),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 Expert BMV's Avatar
    Join Date
    01-13-2020
    Location
    St-Petersburg, Russia
    MS-Off Ver
    2013-2016
    Posts
    1,329

    Re: Sum with dynamic range

    Please Login or Register  to view this content.

  4. #4
    Registered User
    Join Date
    12-03-2020
    Location
    Netherlands
    MS-Off Ver
    office 365 proplus
    Posts
    4

    Re: Sum with dynamic range

    Thanks Glenn for the quick reply, works like a charm!

  5. #5
    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,002

    Re: Sum with dynamic range

    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.

  6. #6
    Registered User
    Join Date
    12-03-2020
    Location
    Netherlands
    MS-Off Ver
    office 365 proplus
    Posts
    4

    Re: Sum with dynamic range

    Hi Glenn (and anyone else who can help),
    The problem I'm working on evolved a bit and more variables entered the stage. So, instead of a SUM, a SUMIFS would work better (I think).
    So I want to do the same thing with the dynamic weeks, but I've added two variables in the sample sheet. I only want the sum of data if those variables are met. Can you please help out again?
    Much appreciated!

    ATD
    Attached Files Attached Files

  7. #7
    Forum Expert BMV's Avatar
    Join Date
    01-13-2020
    Location
    St-Petersburg, Russia
    MS-Off Ver
    2013-2016
    Posts
    1,329

    Re: Sum with dynamic range

    ATD09 Look at the #3.
    Please Login or Register  to view this content.
    Last edited by BMV; 12-03-2020 at 02:14 PM.

  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,002

    Re: Sum with dynamic range

    Yep. Shift to SUMPRODUCT, as combineing years and week numbers is messy with SUMIFS:

    =SUMPRODUCT(($A$2:$A$500=$K$3)*($B$2:$B$500=$J$3)*(($E$2:$E$500+$D$2:$D$500/100>=$H$2+$G$2/100)*(($E$2:$E$500+$D$2:$D$500/100<=$H$5+$G$5/100)*$C$2:$C$500)))
    Attached Files Attached Files

  9. #9
    Forum Expert BMV's Avatar
    Join Date
    01-13-2020
    Location
    St-Petersburg, Russia
    MS-Off Ver
    2013-2016
    Posts
    1,329

    Re: Sum with dynamic range

    Quote Originally Posted by Glenn Kennedy View Post
    Shift to SUMPRODUCT, as combineing years and week numbers is messy with SUMIFS:
    Really ?
    It is not only shorter but quicker
    Please Login or Register  to view this content.
    =SUMPRODUCT(($A$2:$A$500=$K$3)*($B$2:$B$500=$J$3)*(($E$2:$E$500+$D$2:$D$500/100>=$H$2+$G$2/100)*(($E$2:$E$500+$D$2:$D$500/100<=$H$5+$G$5/100)*$C$2:$C$500)))
    41,99219
    =SUMIFS(C:C,E:E,">="&H2,E:E,"<="&H5,A:A,K3,B:B,J3)-SUMIFS(C:C,D:D,"<"&G2,E:E,H2,A:A,K3,B:B,J3)-SUMIFS(C:C,D:D,">"&G5,E:E,H5,A:A,K3,B:B,J3) 26,99219
    Attached Files Attached Files
    Last edited by BMV; 12-03-2020 at 02:26 PM.

  10. #10
    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,002

    Re: Sum with dynamic range

    Whatever...

  11. #11
    Registered User
    Join Date
    12-03-2020
    Location
    Netherlands
    MS-Off Ver
    office 365 proplus
    Posts
    4

    Re: Sum with dynamic range

    Many thanks Glenn and BMV (sorry I overlooked your first reply). I see both options work well. I'll have a look which one I can master myself.

+ 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] Populate Dynamic Array from Cell Values and write to Dynamic Range
    By TFiske in forum Excel Programming / VBA / Macros
    Replies: 3
    Last Post: 03-22-2018, 09:09 AM
  2. [SOLVED] Dynamic Range/Dynamic Chart Using Cell Value for Reference and without CountA
    By kelseygueldalewis in forum Excel General
    Replies: 11
    Last Post: 09-11-2017, 04:52 PM
  3. Match ComboBox with dynamic range, then add Textbox1 to dynamic range
    By Lasse Moe in forum Excel Programming / VBA / Macros
    Replies: 2
    Last Post: 04-07-2014, 01:26 AM
  4. Dynamic Range Column Chart w/ Dynamic Avg Line (Excel 2007)
    By BrokenBiker in forum Excel Charting & Pivots
    Replies: 3
    Last Post: 10-04-2012, 11:40 AM
  5. Fill Dynamic Range From Dynamic Source Range
    By goss in forum Excel General
    Replies: 2
    Last Post: 03-06-2012, 12:05 PM
  6. Replies: 2
    Last Post: 02-02-2006, 04:10 PM
  7. select dynamic range with dynamic start point
    By Juli in forum Excel Programming / VBA / Macros
    Replies: 1
    Last Post: 08-30-2005, 08:05 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