Count Top % Contributors

JV0710

Active Member
Joined
Oct 26, 2006
Messages
429
Office Version
  1. 365
  2. 2016
  3. 2013
Platform
  1. Windows
Good day

Please can anyone help me with this query:

I have a list of about 2000 Suppliers.
In Column A is the Name of the Supplier and
in Column B is the % Contribution of the business I am doing with that Supplier -
Column B is sorted in decending order.

Part 1: In Cell C1 I would like a formula that counts the number of Suppliers that make up 80 % of the contributions. ( the closest to 80% give or take 5% )

Part 2: If the List is not sorted - What would the formula be, to count the TOP 80 % Contributions ( the closest to 80% give or take 5% )

So I would get, for example, 160 of the 2000 suppliers making up the top 80 % of the business.

Thanks

JVN
 

Excel Facts

Which Excel functions can ignore hidden rows?
The SUBTOTAL and AGGREGATE functions ignore hidden rows. AGGREGATE can also exclude error cells and more.
Thanks Richard

I will use your suggestion in the meantime . . . As I mentioned previously, the information will not be sorted in future , the Boss would like to see the detail in Clusters or groups of suppliers (Suppliers by Region) - I will just have to sort on another page and then manually enter the answers into the main spreadsheet.

If there is anyone out there who can help me, It would be much appreciated though.

Thanks

JVN
 
Upvote 0
Hi Lasw10

There is no reason why I cannot use the VBA function provided - In fact I have now done two spreadsheets ( One with the VBA function and one with Richard's solution ) - I just want to spend more time understanding and getting my head around VBA stuff. As I mentioned - I am a newbie as far as VBA goes and I want to explore and understand what I am doing as well.

Thanks for your help

JVN
 
Upvote 0
Sounds like a plan, wasn't chastising but wanted to make sure you weren't avoiding using it because you weren't sure what to do with the code etc...
 
Upvote 0
Good day everyone
Just thought I would let anyone who is interested know, that I managed to work this out ( With the help of a couple of formulae supplied by Peter SSS and Barry Houdini in previous posts ).
I just had to play around with it and edit and sum as an array formula.
Below are two ways to get the answer:
Assuming I have suppliers in Column A : starting on Row 6 down to Row 2840 and the % Contributions of each supplier were in Column B, and I wanted to count how many Suppliers made up the TOP 80% of the % Contributions in Column B . . .

Option 1: confirmed with Ctrl+Shift+enter
=SUM(IF(IF(B$6:B$2840*(SUMIF(B$6:B$2840,">"&B$6:B$2840,B$6:B$2840)<80%)=0,"",B$6:B$2840*(SUMIF(B$6:B$2840,">"&B$6:B$2840,B$6:B$2840)<80%))<>"",1,0))

Option2: confirmed with Ctrl+Shift+enter
=SUM(IF(IF(SUMIF(B$6:B$2840,">"&B6:B2840)<0.8,"1",0)>0,1,0))

I am sure there are other ways as well.
Thanks to those that helped me worked this out.
JVN
Lasw10 - I have not ignored the VBA method that you sugegsted.
 
Upvote 0

Forum statistics

Threads
1,213,517
Messages
6,114,085
Members
448,548
Latest member
harryls

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