Count unique subtotals values

Fin Fang Foom

Well-known Member
Joined
Mar 20, 2005
Messages
598
I have this formula that I got from this forum.

Here is the link:
http://www.mrexcel.com/board2/viewtopic.php?t=155391&postdays=0&postorder=asc&start=30

=SUMPRODUCT(1-SUBTOTAL(3,OFFSET(F3:F23,ROW(F3:F23)-ROW(F3),0,1)),--(F3:F23>0)F3:F23)


Then I'm trying to count unique subtotals values. So I came up with this, Its suppose to ignore duplicates values.

=SUMPRODUCT(1-SUBTOTAL(3,OFFSET(F3:F23,ROW(F3:F23)-ROW(F3),0,1)),--(F3:F23>0)/COUNTIF(A3:A23,A3:A23&""),F3:F23)

Its not caculating correctly.

Look at cell F26 that is the right answer.


Any Help ?
 

Excel Facts

What is the shortcut key for Format Selection?
Ctrl+1 (the number one) will open the Format dialog for whatever is selected.
Fin Fang Foom

I'm trying to count unique subtotals values
Can you clarify the problem? Your formula in F26 is 'adding' not 'counting' and it doesn't seem to be adding 'subtotals' but individual line items. It also includes F21 and F12 which don't seem 'unique'.
 
Upvote 0
Try...

=SUMPRODUCT(1-SUBTOTAL(3,OFFSET(F3:F23,ROW(F3:F23)-ROW(F3),0,1)),--(MATCH(F3:F23&"",F3:F23&"",0)=ROW(F3:F23)-ROW(F3)+1),--(F3:F23>0),F3:F23)

or

=SUM(IF(F3:F23>0,IF(1-SUBTOTAL(3,OFFSET(F3:F23,ROW(F3:F23)-ROW(F3),0,1)),IF(MATCH(F3:F23,F3:F23,0)=ROW(F3:F23)-ROW(F3)+1,F3:F23))))

...confirmed with CONTROL+SHIFT+ENTER.

Hope this helps!
 
Upvote 0
Wow Dominic you got it to work. (y)

Did it took awhile to figuer it out ?

Can you explain break it down that how this formula works, Especially the ROW Function its still a liitle confusing to me that how it works ?


=SUMPRODUCT(1-SUBTOTAL(3,OFFSET(F3:F23,ROW(F3:F23)-ROW(F3),0,1)),--(MATCH(F3:F23&"",F3:F23&"",0)=ROW(F3:F23)-ROW(F3)+1),--(F3:F23>0),F3:F23)


Once again thanks for your magic.
 
Upvote 0
You're very welcome, Fin! Since Aladin has already done a beautiful job of explaining the other parts of the formula here, MATCH and ROW break down as follows...

MATCH(F3:F23&"",F3:F23&"",0) evaluates to:

{1;2;3;4;5;1;7;8;5;1;2;3;4;5;1;7;8;5;1;7;8}

ROW(F3:F23)-ROW(F3)+1 evaluates to:

{1;2;3;4;5;6;7;8;9;10;11;12;13;14;15;16;17;18;19;20;21}

--(MATCH(F3:F23&"",F3:F23&"",0)=ROW(F3:F23)-ROW(F3)+1) evaluates to:

{1;1;1;1;1;0;1;1;0;0;0;0;0;0;0;0;0;0;0;0;0}

Hope this helps!
 
Upvote 0
Domenic doesn't seem to be around, but evaluates to x simply means that the function or part of function will be translated to mean x, just as:

=2+2

evaluates to 4.
 
Upvote 0
just_jon said:
Domenic doesn't seem to be around, but evaluates to x simply means that the function or part of function will be translated to mean x, just as:

=2+2

evaluates to 4.


So its just simple adding in each cell. Well I learned something new.

Thanks just_jon!
 
Upvote 0
It isn't just adding, but the performing of any mathematical/logical operand and/or function call.

It means the results of the formula, not the formula itself.

What a formula in total translates to is what you see in the cell.
 
Upvote 0

Forum statistics

Threads
1,214,649
Messages
6,120,733
Members
448,987
Latest member
marion_davis

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