+ Reply to Thread
Results 1 to 4 of 4

SUMIFS using dynamic array constant

  1. #1
    Registered User
    Join Date
    03-31-2021
    Location
    Mataró, Spain
    MS-Off Ver
    Excel Mac 16.47.1
    Posts
    3

    SUMIFS using dynamic array constant

    Hello,

    This is my first post on this forum. Thank you all for your help!

    I'm trying to sum data in a cell when data in another sheet meet some criteria. The formula I'm using, which is working, is the following:

    =SUM(SUMIFS(Data!$A:$A;Data!$B:$B;MONTH(B$1);Data!$C:$C;{"203*";"204*";"206*";"280*"}))

    This formula I want to copy-paste in many other cells but I would like to avoid manually updating the array constant if the values change later. This I could do it with a named range (via Define name) but it is not straightforward to see which values are being used when there are many rows. I would prefer to have a column with cells containing these values for each row and somehow having them converted to an array constant. Is this possible?

    I would prefer a solution which does not use VisualBasic as other users will use this file.

    Thank you in advance!

    Llorenc

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

    Re: SUMIFS using dynamic array constant

    Welcome to the forum.

    There are instructions at the top of the page explaining how to attach your sample workbook.
    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 Expert XLent's Avatar
    Join Date
    10-13-2010
    Location
    Northumberland, UK
    MS-Off Ver
    various
    Posts
    2,704

    Re: SUMIFS using dynamic array constant

    so, if you're saying you want to store 203*;204*;206*;280* in a cell then you could use something like below, where $C2 holds the delimited criterion

    Formula: copy to clipboard
    Please Login or Register  to view this content.
    in summary, in the above, you're not creating an inline array but rather you're creating an Array of criteria by splitting the delimited string into 1 to n individual elements
    if you modify the string in C2 so the result in B2 should update accordingly... the substitute etc is a bit convoluted as you try to ensure the array of criteria is only as big as the number of elements in the delimited string.

    edit: adding a worked example to illustrate, in case helpful.
    Attached Files Attached Files
    Last edited by XLent; 03-31-2021 at 10:32 AM.

  4. #4
    Registered User
    Join Date
    03-31-2021
    Location
    Mataró, Spain
    MS-Off Ver
    Excel Mac 16.47.1
    Posts
    3

    Re: SUMIFS using dynamic array constant

    Hello,

    I don't get how this formula exactly works but it does, thank you very much!

    I suppose it parses the string and outputs an array. I will have to investigate this use of row() and index().

    Llorenc

+ 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. SUMPRODUCT/SUMIFS Dynamic array doesn't works
    By regoroes in forum Excel General
    Replies: 5
    Last Post: 01-04-2018, 03:01 AM
  2. [SOLVED] SUMIFS with multiple criteria but only with one constant ARRAY?
    By Hellgun in forum Excel Formulas & Functions
    Replies: 3
    Last Post: 04-26-2017, 02:21 AM
  3. No VBA method to create a dynamic array constant
    By akshaythakker in forum Excel Formulas & Functions
    Replies: 11
    Last Post: 09-05-2016, 01:51 PM
  4. [SOLVED] Determining dynamic array length on a constant number of observations
    By lostest in forum Excel Programming / VBA / Macros
    Replies: 9
    Last Post: 10-13-2015, 04:28 PM
  5. SUMIFS with Array Constant Fails
    By zCJH4254 in forum Excel Formulas & Functions
    Replies: 6
    Last Post: 07-20-2014, 11:08 AM
  6. [SOLVED] Dynamic Array, Index & Match, SUMIFS Formula Help!
    By garrett.grillo in forum Excel Formulas & Functions
    Replies: 12
    Last Post: 05-03-2014, 09:27 PM
  7. Constant Array?
    By Pherion in forum Excel Programming / VBA / Macros
    Replies: 2
    Last Post: 07-27-2009, 05:47 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