Hi Johann, That is another example usage of a boolean expression as a criterion. In your example you could actually omit the -- since you are multiplying the expression already. The multiplication will also coerce the boolean to 0 or 1:
{ =LARGE(($E$1:$E$122=$G1)*$F$1:$F$122,COUNTIF($G$1:$G1,$G1)) } The formula builds an array of 122 elements (the size of the ranges e1:e122 / f1:f122). Each element equals [0 or (1 if E=(thisrow's G))] * [F]. That resolves to an array of 0's and values from column G. That array is then sorted from largest to smallest. Then the CountIf is calculated: The CountIf expression counts the number of occurences of [this row's G] in [this and prior row's G values] let's call that count "n". Finally, Excel returns the nth value from the sorted array. _E F G formula evaluation _ 2 100 1 large({0,0,150,0,0,180,0,0,50},1) = large({180,150,50,..},1) = 180 4 200 4 large({0,200,0,0,220,0,0,130,0},1) = large({220,200,130,..},1) = 220 1 150 2 large({100,0,0,250,0,0,75,0,0},1) = large({250,100,75,..},1) = 250 2 250 4 large({0,200,0,0,220,0,0,130,0},2) = large({220,200,130,..},2) = 200 4 220 1 large({0,0,150,0,0,180,0,0,50},2) = large({180,150,50,..},2) = 150 1 180 2 large({100,0,0,250,0,0,75,0,0},2) = large({250,100,75,..},2) = 100 2 75 1 large({0,0,150,0,0,180,0,0,50},3) = large({180,150,50,..},3) = 50 4 130 4 large({0,200,0,0,220,0,0,130,0},3) = large({220,200,130,..},3) = 130 1 50 1 large({0,0,150,0,0,180,0,0,50},4) = large({180,150,50,0,..},4) = 0 ... My brain is kind of tired and I'm not sure exactllllly sure what the overall function of your formula is at the moment though :) Asa -----Original Message----- From: excel-macros@googlegroups.com [mailto:excel-macros@googlegroups.com] On Behalf Of johann Sent: Friday, February 24, 2012 12:49 PM To: MS EXCEL AND VBA MACROS Subject: Re: $$Excel-Macros$$ Meaning of minus minus or -- in an Excel function what about : {=LARGE(- -($E$1:$E$122=$G1)*$F$1:$F$122,COUNTIF($G$1:$G1,$G1))} ? -- FORUM RULES (986+ members already BANNED for violation) 1) Use concise, accurate thread titles. Poor thread titles, like Please Help, Urgent, Need Help, Formula Problem, Code Problem, and Need Advice will not get quick attention or may not be answered. 2) Don't post a question in the thread of another member. 3) Don't post questions regarding breaking or bypassing any security measure. 4) Acknowledge the responses you receive, good or bad. 5) Cross-promotion of, or links to, forums competitive to this forum in signatures are prohibited. NOTE : Don't ever post personal or confidential data in a workbook. Forum owners and members are not responsible for any loss. ---------------------------------------------------------------------------- -------------------------- To post to this group, send email to <mailto:excel-macros@googlegroups.com> excel-macros@googlegroups.com -- FORUM RULES (986+ members already BANNED for violation) 1) Use concise, accurate thread titles. Poor thread titles, like Please Help, Urgent, Need Help, Formula Problem, Code Problem, and Need Advice will not get quick attention or may not be answered. 2) Don't post a question in the thread of another member. 3) Don't post questions regarding breaking or bypassing any security measure. 4) Acknowledge the responses you receive, good or bad. 5) Cross-promotion of, or links to, forums competitive to this forum in signatures are prohibited. NOTE : Don't ever post personal or confidential data in a workbook. Forum owners and members are not responsible for any loss. ------------------------------------------------------------------------------------------------------ To post to this group, send email to excel-macros@googlegroups.com