SOLVED

summing with multiple criteria

Brass Contributor

I would like to find the total popo (second column below) for each category name in the first column for each class (third column) only for rows that are not empty in the last column (criteria).

 

Any help?

 

Namepopclasscriteria
A38107Medium 
A27720Medium 
A80542Medium 
A55828Mediumk
B23771Medium 
B99218Medium 
C30365Low 
C35420Very Highs-z-y
C8930Highy-h-f

 

Thank you so much.

11 Replies

@Lycias 

It could be done with PivotTable. Add data to data model creating it and use measure

Total pop:=CALCULATE( SUM(Table1[pop]), NOT( ISBLANK( Table1[criteria] ) ) )

Result is

image.png

@Lycias 

With Class added to the pivot table:

@Sergi thanks for the quick respponse. how about if I am trying to pull this calculated value into another table with other values I am pulling from other worksheets...is there an alternative formula I can use?

@Lycias , you just use another data source - if I understood the question correctly.

best response confirmed by Lycias (Brass Contributor)
Solution

@Lycias If using Excel 365 you can use dynamic arrays to FILTER the three lines and then SUMIFS to get the totals. Two formulas and a third to pull the data to another table.

bosinander_3-1631999680814.png

 

 

Formula 1, G3

  1. defines the data range as a3:d11.
  2. The wanted data is all rows in dataRange and column 1 and 3.
  3. Criteria is all rows (zero means all rows when indexing only one column) column 4
  4. Output is data columns where the length of the criteria column is greater than 0

=LET(dataRange;A3:D11;
dataCols;INDEX(dataRange;SEQUENCE(ROWS(dataRange));{1\3});
criteraCol;INDEX(dataRange;0;4);
output;FILTER(dataCols;LEN(criteraCol)>0);
output
)

The last parameter "output" may be changed to the other names for exploring each part.

 

Formula 2, i3

G3# is the dynamic range anchored in cell G3:

INDEX(G3#;0;1) means all rows (zero) and column 1 being the filtered names.
D3:D11;"<>" means not empty.

=SUMIFS(B3:B11;A3:A11;INDEX(G3#;0;1);C3:C11;INDEX(G3#;0;2);D3:D11;"<>")

 

Formula 3, p3

Concatenates m3:m14 with a pipe and n3:n14.
The combination is then xlookup'ed in the same combination of name and class. 

=XLOOKUP(M3:M14 & "|" & N3:N14;INDEX(G3#;0;1) & "|" & INDEX(G3#;0;2);I3#;"")

 

Formula 1 and 2 gives in much result similar to a pivot table but this does not need manual updating.

The solution uses functions as of now available only in Excel 365 but will be available in Excel 2021 .

@Lycias Using Tables, the solution is more readable and expands the source data. Added another sheet using Tables.

@bosinander thanks so much, this worked perfectly fine. I added another sumif column to sum column I if column G is the same. let me know if there is a way to do it once in column I sumifs formula.
@bosinander Perfect, super helpful. Thanks a lot.

@Lycias A summary by Name only..?
dataCols (output dimensions) is then indexing only the first column (zero to get all rows).
Since there will be duplicates, UNIQUE is added to get them only once each.

bosinander_0-1632041682659.png

=LET(dataRange;A3:D23;
dataCols;INDEX(dataRange;0;1);
criteraCol;INDEX(dataRange;0;4);
names;FILTER(dataCols;LEN(criteraCol)>0);
output;UNIQUE(names);
output
)

@bosinander, this is what get on a sample of the data......somehow the SUMIFS doesn't seem to recognize that I want the sum for each region, for each class only when it is not empty for the cov column. kindly se attached. not sure where it is not right. For this region, the sum I want should be 148 530 for class "high" but it is giving me a total which i know is for all "high" for region a not only those "high" that are not empty in column "cov". Thanks!

@bosinander, I saw that although the empty cells under cov look blank, they are not really blank. I corrected that and now it works perfectly. Thanks for the handy formula and approach. You may disregard my previous post.
1 best response

Accepted Solutions
best response confirmed by Lycias (Brass Contributor)
Solution

@Lycias If using Excel 365 you can use dynamic arrays to FILTER the three lines and then SUMIFS to get the totals. Two formulas and a third to pull the data to another table.

bosinander_3-1631999680814.png

 

 

Formula 1, G3

  1. defines the data range as a3:d11.
  2. The wanted data is all rows in dataRange and column 1 and 3.
  3. Criteria is all rows (zero means all rows when indexing only one column) column 4
  4. Output is data columns where the length of the criteria column is greater than 0

=LET(dataRange;A3:D11;
dataCols;INDEX(dataRange;SEQUENCE(ROWS(dataRange));{1\3});
criteraCol;INDEX(dataRange;0;4);
output;FILTER(dataCols;LEN(criteraCol)>0);
output
)

The last parameter "output" may be changed to the other names for exploring each part.

 

Formula 2, i3

G3# is the dynamic range anchored in cell G3:

INDEX(G3#;0;1) means all rows (zero) and column 1 being the filtered names.
D3:D11;"<>" means not empty.

=SUMIFS(B3:B11;A3:A11;INDEX(G3#;0;1);C3:C11;INDEX(G3#;0;2);D3:D11;"<>")

 

Formula 3, p3

Concatenates m3:m14 with a pipe and n3:n14.
The combination is then xlookup'ed in the same combination of name and class. 

=XLOOKUP(M3:M14 & "|" & N3:N14;INDEX(G3#;0;1) & "|" & INDEX(G3#;0;2);I3#;"")

 

Formula 1 and 2 gives in much result similar to a pivot table but this does not need manual updating.

The solution uses functions as of now available only in Excel 365 but will be available in Excel 2021 .

View solution in original post