Sumifs & rank combined

Zubair

Active Member
Joined
Jul 4, 2009
Messages
304
Office Version
  1. 2016
Platform
  1. Windows
Hi experts,

I need combined formula in column D with Sumifs and rank based on the given data sheet and shown result.

Data
Actual/PlanAreaDescriptionYearVolumeTurnover US$Std Cost US$Std Gross Profit US$GM CPL
ActualsArea Manager 1SetJet 50 CD Bulk
2020​
2,000114,918112,0102,9081.45
ActualsArea Manager 1SetJet 50 CD 1 ltr
2021​
4,563305,906306,020(114)(0.03)
ActualsArea Manager 1SetPlus 20W50 CF4 1 ltr
2021​
40727,72026,1621,5583.83
ActualsArea Manager 1SetJet 50 CD Bulk
2020​
2,000114,918115,121(203)(0.10)
ActualsArea Manager 1SetJet 50 CD 1 ltr
2021​
6,676447,513457,201(9,688)(1.45)
ActualsArea Manager 4BetJet 20W50 CNG CD 4 ltr
2020​
5,523566,690566,0006900.12
ActualsArea Manager 5BetJet 20W50 CNG CD 4 ltr
2021​
23,9422,456,6172,300,000156,6176.54


Result
AreaDescriptionYearVolume
Area Manager 5BetJet 20W50 CNG CD 4 ltr
2021​
23,942
Area Manager 1SetJet 50 CD 1 ltr
2021​
6,676
Area Manager 1SetJet 50 CD 1 ltr
2021​
4,563
Area Manager 1SetPlus 20W50 CF4 1 ltr
2021​
407
 

Excel Facts

Does the VLOOKUP table have to be sorted?
No! when you are using an exact match, the VLOOKUP table can be in any order. Best-selling items at the top is actually the best.
Like this?
Sorry, I didn't use SUMIFS or RANK but I think it does what you want. :cool:

21 04 05.xlsm
ABCDEFGHI
1Actual/PlanAreaDescriptionYearVolumeTurnover US$Std Cost US$Std Gross Profit US$GM CPL
2ActualsArea Manager 1SetJet 50 CD Bulk20202,000114,918112,0102,9081.45
3ActualsArea Manager 1SetJet 50 CD 1 ltr20214,563305,906306,020-114-0.03
4ActualsArea Manager 1SetPlus 20W50 CF4 1 ltr202140727,72026,1621,5583.83
5ActualsArea Manager 1SetJet 50 CD Bulk20202,000114,918115,121-203-0.1
6ActualsArea Manager 1SetJet 50 CD 1 ltr20216,676447,513457,201-9,688-1.45
7ActualsArea Manager 4BetJet 20W50 CNG CD 4 ltr20205,523566,690566,0006900.12
8ActualsArea Manager 5BetJet 20W50 CNG CD 4 ltr202123,9422,456,6172,300,000156,6176.54
9
10
11AreaDescriptionYearVolume
12Area Manager 5BetJet 20W50 CNG CD 4 ltr202123,942
13Area Manager 1SetJet 50 CD 1 ltr20216,676
14Area Manager 1SetJet 50 CD 1 ltr20214,563
15Area Manager 1SetPlus 20W50 CF4 1 ltr2021407
SUM
Cell Formulas
RangeFormula
D12:D15D12=AGGREGATE(14,6,E$2:E$8/((B$2:B$8=A12)*(C$2:C$8=B12)*(D$2:D$8=C12)),COUNTIFS(A$12:A12,A12,B$12:B12,B12,C$12:C12,C12))
 
Upvote 0
Solution
Yes Peter I like it, thanks for the quick answer as always
 
Upvote 0
I have files mostly contained Sumifs formula and it will take large number of hours to change them to AGGREGATE, so if possible please share ranking with Sumifs.
 
Upvote 0
SUMIFS does not seem relevant to the problem as far as I can see.

Besides, if you have to change the formulas anyway, why not change to AGGREGATE as you only have to change one then copy it down the column.
 
Upvote 0
Why is I want single figure of Area Manager 1 for SetJet 50 CD 1 ltr D13 +D14, please tell how in AGGRIGATE ?
 
Upvote 0
Why is I want single figure of Area Manager 1 for SetJet 50 CD 1 ltr D13 +D14, please tell how in AGGRIGATE ?
Well, that is a very different question to the original one!
So that can be done with SUMIFS

21 04 05.xlsm
ABCDE
1Actual/PlanAreaDescriptionYearVolume
2ActualsArea Manager 1SetJet 50 CD Bulk20202,000
3ActualsArea Manager 1SetJet 50 CD 1 ltr20214,563
4ActualsArea Manager 1SetPlus 20W50 CF4 1 ltr2021407
5ActualsArea Manager 1SetJet 50 CD Bulk20202,000
6ActualsArea Manager 1SetJet 50 CD 1 ltr20216,676
7ActualsArea Manager 4BetJet 20W50 CNG CD 4 ltr20205,523
8ActualsArea Manager 5BetJet 20W50 CNG CD 4 ltr202123,942
9
10
11AreaDescriptionVolume
12Area Manager 5BetJet 20W50 CNG CD 4 ltr23,942
13Area Manager 1SetJet 50 CD 1 ltr11,239
14Area Manager 1SetPlus 20W50 CF4 1 ltr407
SUM (2)
Cell Formulas
RangeFormula
C12:C14C12=SUMIFS(E$2:E$8,B$2:B$8,A12,C$2:C$8,B12)
 
Upvote 0

Forum statistics

Threads
1,215,411
Messages
6,124,759
Members
449,187
Latest member
hermansoa

We've detected that you are using an adblocker.

We have a great community of people providing Excel help here, but the hosting costs are enormous. You can help keep this site running by allowing ads on MrExcel.com.
Allow Ads at MrExcel

Which adblocker are you using?

Disable AdBlock

Follow these easy steps to disable AdBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the icon in the browser’s toolbar.
2)Click on the "Pause on this site" option.
Go back

Disable AdBlock Plus

Follow these easy steps to disable AdBlock Plus

1)Click on the icon in the browser’s toolbar.
2)Click on the toggle to disable it for "mrexcel.com".
Go back

Disable uBlock Origin

Follow these easy steps to disable uBlock Origin

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back

Disable uBlock

Follow these easy steps to disable uBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back
Back
Top