Give back the most/least profitable product

Amaden95

New Member
Joined
May 11, 2021
Messages
3
Office Version
  1. 2019
  2. 2016
Platform
  1. Windows
Hey Guys/Girls, I need some help with getting back the most profitable product in a single cell and a least profitable in another. I had a working formula but it didn't worked with empty spaces.

I have a summary sheet and a second data sheet where i store all the information.

On the summary sheet all I need to see is the most and the least profitable.

Profitability.xlsx
AB
1Name of product
2Most profitable
3Least profitable
Summary


on the second sheet let's call it "data" i have a column with different name of products and next to them the profit they generated, each a bit different.

Profitability.xlsx
ABC
1Name of productProfitMinus
2a100
3b200
4a020
5a1000
6b00
7c030
8c020
9c500
10d100
11b300
12b00
13c060
14a010
Data


All I need back is the name of the product that made the most and least profit withouth giving an error when i extend it over hundreds of empty space.

If anyone got an answer please help.
Thanks.
 

Excel Facts

Remove leading & trailing spaces
Save as CSV to remove all leading and trailing spaces. It is faster than using TRIM().
@Amaden95 Welcome to MrExcel

Maybe try
MRXLMAY21.xlsm
AB
1Product
2Mosta
3Leastc
Sheet3
Cell Formulas
RangeFormula
B2B2=INDEX(Data!$A:$A,MATCH(MAX(Data!B:B),Data!B:B,0))
B3B3=INDEX(Data!$A:$A,MATCH(MAX(Data!C:C),Data!C:C,0))


Hope that helps
 
Upvote 0
@Amaden95 Welcome to MrExcel

Maybe try
MRXLMAY21.xlsm
AB
1Product
2Mosta
3Leastc
Sheet3
Cell Formulas
RangeFormula
B2B2=INDEX(Data!$A:$A,MATCH(MAX(Data!B:B),Data!B:B,0))
B3B3=INDEX(Data!$A:$A,MATCH(MAX(Data!C:C),Data!C:C,0))


Hope that helps
Thanks for the help, but this is not exactly what im looking for.
If I'm not wrong, this formula gives back the name of the product which generated the highest single profit.
What 'm looking for is to sum every profit A generated and sum the profit B generated and C.. and so on separately and check which is the highest and the lowest overall.
 
Upvote 0
How about:

Book1
ABCDEFG
1Name of productProfitMinusName of product
2a100Most profitablea80
3b200Least profitablec-60
4a020
5a1000
6b00
7c030
8c020
9c500
10d100
11b300
12b00
13c060
14a010
Sheet3
Cell Formulas
RangeFormula
F2F2=INDEX(A$2:A$14,MATCH(MAX(SUMIF(A$2:A$14,A$2:A$14,B$2:B$14)-SUMIF(A$2:A$14,A$2:A$14,C$2:C$14)),SUMIF(A$2:A$14,A$2:A$14,B$2:B$14)-SUMIF(A$2:A$14,A$2:A$14,C$2:C$14),0))
G2:G3G2=SUMIF(A$2:A$14,F2,B$2:B$14)-SUMIF(A$2:A$14,F2,C$2:C$14)
F3F3=INDEX(A$2:A$14,MATCH(MIN(SUMIF(A$2:A$14,A$2:A$14,B$2:B$14)-SUMIF(A$2:A$14,A$2:A$14,C$2:C$14)),SUMIF(A$2:A$14,A$2:A$14,B$2:B$14)-SUMIF(A$2:A$14,A$2:A$14,C$2:C$14),0))
Press CTRL+SHIFT+ENTER to enter array formulas.
 
Upvote 0
Solution
How about:

Book1
ABCDEFG
1Name of productProfitMinusName of product
2a100Most profitablea80
3b200Least profitablec-60
4a020
5a1000
6b00
7c030
8c020
9c500
10d100
11b300
12b00
13c060
14a010
Sheet3
Cell Formulas
RangeFormula
F2F2=INDEX(A$2:A$14,MATCH(MAX(SUMIF(A$2:A$14,A$2:A$14,B$2:B$14)-SUMIF(A$2:A$14,A$2:A$14,C$2:C$14)),SUMIF(A$2:A$14,A$2:A$14,B$2:B$14)-SUMIF(A$2:A$14,A$2:A$14,C$2:C$14),0))
G2:G3G2=SUMIF(A$2:A$14,F2,B$2:B$14)-SUMIF(A$2:A$14,F2,C$2:C$14)
F3F3=INDEX(A$2:A$14,MATCH(MIN(SUMIF(A$2:A$14,A$2:A$14,B$2:B$14)-SUMIF(A$2:A$14,A$2:A$14,C$2:C$14)),SUMIF(A$2:A$14,A$2:A$14,B$2:B$14)-SUMIF(A$2:A$14,A$2:A$14,C$2:C$14),0))
Press CTRL+SHIFT+ENTER to enter array formulas.
Thank you Eric!
Works wonderfully.
 
Upvote 0

Forum statistics

Threads
1,224,820
Messages
6,181,159
Members
453,021
Latest member
Justyna P

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