Forum Discussion
Countifs
This only applies to Excel 365.
= LET(
distinctSalesManager, UNIQUE(SalesManager),
distinctSalesPerson, UNIQUE(SalesPerson),
totalSales, SUMIFS(SalesAmount, SalesPerson, distinctSalesPerson),
qualifies, SIGN(totalSales>=Threshold),
personsManager, XLOOKUP(distinctSalesPerson, SalesPerson, SalesManager),
matrix, SIGN(TRANSPOSE(personsManager) = distinctSalesManager),
CHOOSE({1,2}, distinctSalesManager, MMULT(matrix, qualifies)))It calculates the total sales for each sales person, then build a matrix to show which sales manager the sales person reports to. Matrix multiplication is then used to count the number of salesmen managed by the given sales manager have met the threshold sales value.
- DKoontzAug 18, 2021Iron ContributorThis is gnarly, but isn't it basically just rebuilding a pivot table?
- PeterBartholomew1Aug 19, 2021Silver Contributor
I don't think so. The SUMIFS function with arrays for the criteria fields can replicate the values one would obtain with a pivot table, but I don't think the calculation is executed by the same code. Since I use Excel 365 Insider beta channel, I have access to new functions that allow solutions to depart even further from the norms of traditional spreadsheet.
= MAP(UNIQUE(SalesManager), LAMBDA(mgr, LET( teamMember, UNIQUE(FILTER(SalesPerson, SalesManager=mgr)), teamSalesAmount, SUMIFS(SalesAmount, SalesPerson, teamMember), SUM(SIGN(teamSalesAmount > Threshold)) ) ) )That is:
- for each distinct sales manager, filter the sales person list to return the managers team;
- for each team member, calculate their total sales to date;
- count the number that exceed the cut-off value.
The greatest challenge might be even recognising that the offered solution is an Excel worksheet formula!
- DKoontzAug 20, 2021Iron Contributor
This is seriously so cool, way beyond my current scope, I don't have MAP or LAMBDA access with my current subscription. Where did you guys (SergeiBaklan too) learn this stuff? I'm always trying to get better with excel and you've blown my mind with building these custom functions and matrixes.
Totally next level stuff.
- SergeiBaklanAug 19, 2021Diamond Contributor
PivotTable requires refresh, from that point of view formulas is always better. But if go this way
- load by Power Query named cell Threshold to data model;
- creating PivotTable add data to data model;
- couple of measures
sumAmount:=SUM ( Range[Sales Amount] ) Top Staff:=SUMX ( VALUES ( Range[Sales Person] ), INT ( [sumAmount] > VALUES ( Threshold[Column1] ) ) )second one into PivotTable: