Rank IF / Sum product - Multiple Criteria

cunningAce

Board Regular
Joined
Dec 21, 2017
Messages
91
Office Version
  1. 365
Platform
  1. Windows
I am working with the following sample data.


Product CodeCategory12345rank
123Low10203040502
456Low5101520253
789Med246810
234Med3691215
567High100200300400500
345High20406080100
678Low15304560751
Week No1CategoryLow

<colgroup><col><col><col span="6"></colgroup><tbody>
</tbody>
I have a sum product formula as below acting as a 'rank if' function based on the criteria from drop down list in D12, 'Category'

=IF(B2=$D$12,SUMPRODUCT(--($B$2:$B$8=$D$12),--(C2<$C$2:$C$8))+1,"")

This works fine but id like to add a second criteria, 'Week No' another drop down list in B12.

How would I update the formula; I assume the bit in red, so the rank column is determined by both category and weeks number selected from the drop down lists.

Thanks in advance
 

Excel Facts

Links? Where??
If Excel says you have links but you can't find them, go to Formulas, Name Manager. Look for old links to dead workbooks & delete.
This just might do it.

=IF(B2=$D$12,SUMPRODUCT(--($B$2:$B$8=$D$12),--(INDEX(C2:G2,,$B$12) < INDEX($C$2:$G$8,,$B$12)))+1,"")
 
Upvote 0
Thank you for your answer; works perfectly in this example :)
I am trying to apply this to a data set though where the Week numbers don't necessarily correspond to the column number you are passing in the index function that you suggested to use.
The first column of sales data for example could actually be labelled Week 25, in which case this formula doesn't work.
Can this be implemented.

Thanks again for your help already
 
Upvote 0
Try this:
Code:
 =IF(B2=$D$12,SUMPRODUCT(($B$2:$B$8=$D$12)*(OFFSET(C2,,$B$12-1)<OFFSET($C$2:$C$8,,$B$12-1)))+1,"")
<offset($c$2:$c$8,,$b$12-1)))+1,"")[ code]<offset($c$2:$c$8,,$b$12-1)))+1,"")[="" code]<offset($c$2:$c$8,,$b$12-1)))+1,"")<offset($c$2:$c$8,,$b$12-1)))+1,"")<offset($c$2:$c$8,,$b$12-1)))+1,"")[="" code]<offset($c$2:$c$8,,$b$12-1)))+1,"")<offset($c$2:$c$8,,$b$12-1)))+1,"")<="" html=""></offset($c$2:$c$8,,$b$12-1)))+1,"")[>
 
Last edited:
Upvote 0
Thanks for the response,

This returns the correct category and week number as the selections made but the rank returned is '1' for all
Might be a simple fix but I'm not great with the offset function

Thanks
 
Upvote 0
Odd, it works perfectly with your sample data. I did have some trouble getting this forum to see my formula correctly (took several attempts before it would show anything after the less-than sign), so I wonder if you got it all. It should have a less-than symbol after
=IF(B2=$D$12,SUMPRODUCT(($B$2:$B$8=$D$12)*(OFFSET(C2,,$B$12-1)

and then:

OFFSET($C$2:$C$8,,$B$12-1)))+1,"")
 
Upvote 0
I have all the formula correctly.
If you change the week numbers from 1-5 to 20-24 instead the formula returns all 1's for the selections selected from the B12 and D12, it returns a 1 for each, rather than ranking them.

Thanks
 
Upvote 0
Ah, I see.
Code:
=IF(B2=$D$12,SUMPRODUCT(($B$2:$B$8=$D$12)*(OFFSET(C2,,MATCH($B$12,$C$1:$G$1,0)-1)<OFFSET($C$2:$C$8,,MATCH($B$12,$C$1:$G$1,0)-1)))+1,"")
 
Last edited:
Upvote 0

Forum statistics

Threads
1,214,423
Messages
6,119,398
Members
448,892
Latest member
amjad24

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