Forum Discussion

James_Buist's avatar
James_Buist
Brass Contributor
Jul 27, 2024
Solved

Generating a 2D array from sumifs on the columns of another 2D array

I have a 2D array of costs by month and want a sumif equivalent based on another dynamic array of Divisions see below. i.e. Jan Div 1 is in M2 so I can refer to this as M2# to get the full table Jan ...
  • djclements's avatar
    Jul 28, 2024

    James_Buist As a variant, here's a couple of SUMIFS options:

     

    =LET(
        arr, LAMBDA(n, CHOOSE(n, K10#, SEQUENCE(, COLUMNS(M2#)))),
        MAP(arr({1}), arr({2}), LAMBDA(r,c, SUMIFS(INDEX(M2#,, c), K2#, r)))
    )

     

    -OR-

     

    =DROP(REDUCE(0, SEQUENCE(COLUMNS(M2#)), LAMBDA(p,c, HSTACK(p, SUMIFS(INDEX(M2#,, c), K2#, K10#)))),, 1)

     

    The latter should be more efficient because there are fewer iterations, but you probably won't notice a difference on a relatively small dataset.

     

    Having said that, I'd be more interested to see how the actual data source is organized. Obviously, cells K2 and M2 contain formulas that reference another dataset, because you're using the spilled range operator (#). If the data source was arranged vertically in a table with columns for "Division", "Month" and "Amount", you could easily summarize the data using a single SUMIFS formula or a pivot table.

     

    Please see the attached example file, if needed...

Resources