Sum up unique values only

amolvijay

Board Regular
Joined
Nov 13, 2012
Messages
102
Office Version
  1. 365
Platform
  1. Windows
Hi Experts,

I am working on table where Column A have Item listed and column F till K have month wise status for each of the team member based on the start and end date. There are chances that few are available and proposed for next assignment in the same month. When I have to calculate UNIQUE values for that particular month for particular designation. Please help, with normal countif, excel is considering duplicate values as well. It should look for column A and should be able to make a calculation that ONLY ONE is being considered for summation.

[TABLE="class: grid, width: 1183"]
<tbody>[TR]
[TD][/TD]
[TD]A
[/TD]
[TD]B
[/TD]
[TD]C
[/TD]
[TD]D
[/TD]
[TD]E
[/TD]
[TD]F
[/TD]
[TD]G
[/TD]
[TD]H
[/TD]
[TD]I
[/TD]
[TD]J
[/TD]
[TD]K
[/TD]
[/TR]
[TR]
[TD]1
[/TD]
[TD]Name[/TD]
[TD]Desig[/TD]
[TD]Available[/TD]
[TD]Start D[/TD]
[TD]End D[/TD]
[TD]OCT
[/TD]
[TD]NOV
[/TD]
[TD]DEC
[/TD]
[TD]JAN
[/TD]
[TD]FEB
[/TD]
[TD]MAR
[/TD]
[/TR]
[TR]
[TD]2
[/TD]
[TD]Mr. Sam
[/TD]
[TD]VP
[/TD]
[TD]A
[/TD]
[TD]2/1/2015
[/TD]
[TD]3/31/2015
[/TD]
[TD]
[/TD]
[TD]
[/TD]
[TD]
[/TD]
[TD]
[/TD]
[TD]VP-A
[/TD]
[TD]VP-A
[/TD]
[/TR]
[TR]
[TD]3
[/TD]
[TD]Mr. Bill
[/TD]
[TD]AVP
[/TD]
[TD]A
[/TD]
[TD]1/29/2015
[/TD]
[TD]2/19/2015
[/TD]
[TD]
[/TD]
[TD]
[/TD]
[TD]
[/TD]
[TD]AVP-A
[/TD]
[TD]AVP-A
[/TD]
[TD]
[/TD]
[/TR]
[TR]
[TD]4
[/TD]
[TD]Mr. John
[/TD]
[TD]SRMNG
[/TD]
[TD]A
[/TD]
[TD]10/1/2014
[/TD]
[TD]2/19/2015
[/TD]
[TD]SRMNG-A
[/TD]
[TD]SRMNG-A
[/TD]
[TD]SRMNG-A
[/TD]
[TD]SRMNG-A
[/TD]
[TD]SRMNG-A
[/TD]
[TD]
[/TD]
[/TR]
[TR]
[TD]5
[/TD]
[TD]Mr. John
[/TD]
[TD]SRMNG
[/TD]
[TD]P
[/TD]
[TD]2/20/2015
[/TD]
[TD]3/31/2015
[/TD]
[TD]
[/TD]
[TD]
[/TD]
[TD]
[/TD]
[TD]
[/TD]
[TD]SRMNG-P
[/TD]
[TD]SRMNG-P
[/TD]
[/TR]
[TR]
[TD]6
[/TD]
[TD]Mr. Harry
[/TD]
[TD]INTERN
[/TD]
[TD]A
[/TD]
[TD]1/27/2015
[/TD]
[TD]2/15/2015
[/TD]
[TD]
[/TD]
[TD]
[/TD]
[TD]
[/TD]
[TD]INTERN-A
[/TD]
[TD]INTERN-A
[/TD]
[TD]
[/TD]
[/TR]
[TR]
[TD]7
[/TD]
[TD]Mr. Harry
[/TD]
[TD]INTERN
[/TD]
[TD]P
[/TD]
[TD]2/16/2015
[/TD]
[TD]3/31/2015
[/TD]
[TD]
[/TD]
[TD]
[/TD]
[TD]
[/TD]
[TD]
[/TD]
[TD]INTERN-P
[/TD]
[TD]INTERN-P
[/TD]
[/TR]
[TR]
[TD]8
[/TD]
[TD]Ms. Rebecca
[/TD]
[TD]INTERN
[/TD]
[TD]A
[/TD]
[TD]1/27/2015
[/TD]
[TD]2/15/2015
[/TD]
[TD]
[/TD]
[TD]
[/TD]
[TD]
[/TD]
[TD]INTERN-A
[/TD]
[TD]INTERN-A
[/TD]
[TD]
[/TD]
[/TR]
[TR]
[TD]9
[/TD]
[TD]Ms. Rebecca
[/TD]
[TD]INTERN
[/TD]
[TD]P
[/TD]
[TD]2/16/2015
[/TD]
[TD]3/31/2015
[/TD]
[TD]
[/TD]
[TD]
[/TD]
[TD]
[/TD]
[TD]
[/TD]
[TD]INTERN-P
[/TD]
[TD]INTERN-P
[/TD]
[/TR]
[TR]
[TD]10
[/TD]
[TD]Ms. Suzan
[/TD]
[TD]INTERN
[/TD]
[TD]A
[/TD]
[TD]1/27/2015
[/TD]
[TD]2/15/2015
[/TD]
[TD]
[/TD]
[TD]
[/TD]
[TD]
[/TD]
[TD]INTERN-A
[/TD]
[TD]INTERN-A
[/TD]
[TD]
[/TD]
[/TR]
[TR]
[TD]11
[/TD]
[TD]Ms. Suzan
[/TD]
[TD]INTERN
[/TD]
[TD]P
[/TD]
[TD]2/16/2015
[/TD]
[TD]3/31/2015
[/TD]
[TD]
[/TD]
[TD]
[/TD]
[TD]
[/TD]
[TD]
[/TD]
[TD]INTERN-P
[/TD]
[TD]INTERN-P
[/TD]
[/TR]
[TR]
[TD]12
[/TD]
[TD]Mr. David
[/TD]
[TD]INTERN
[/TD]
[TD]A
[/TD]
[TD]1/27/2015
[/TD]
[TD]2/15/2015
[/TD]
[TD]
[/TD]
[TD]
[/TD]
[TD]
[/TD]
[TD]INTERN-A
[/TD]
[TD]INTERN-A
[/TD]
[TD]
[/TD]
[/TR]
[TR]
[TD]13
[/TD]
[TD]Mr. David
[/TD]
[TD]INTERN
[/TD]
[TD]P
[/TD]
[TD]2/16/2015
[/TD]
[TD]3/31/2015
[/TD]
[TD]
[/TD]
[TD]
[/TD]
[TD]
[/TD]
[TD]
[/TD]
[TD]INTERN-P
[/TD]
[TD]INTERN-P
[/TD]
[/TR]
[TR]
[TD]14
[/TD]
[TD]Mr. Jim
[/TD]
[TD]INTERN
[/TD]
[TD]A
[/TD]
[TD]1/27/2015
[/TD]
[TD]2/15/2015
[/TD]
[TD]
[/TD]
[TD]
[/TD]
[TD]
[/TD]
[TD]INTERN-A
[/TD]
[TD]INTERN-A
[/TD]
[TD]
[/TD]
[/TR]
[TR]
[TD]15
[/TD]
[TD]Mr. Jim
[/TD]
[TD]INTERN
[/TD]
[TD]P
[/TD]
[TD]2/16/2015
[/TD]
[TD]3/31/2015
[/TD]
[TD]
[/TD]
[TD]
[/TD]
[TD]
[/TD]
[TD]
[/TD]
[TD]INTERN-P
[/TD]
[TD]INTERN-P
[/TD]
[/TR]
[TR]
[TD]16
[/TD]
[TD]Mr. Garry
[/TD]
[TD]ENGG
[/TD]
[TD]P
[/TD]
[TD]2/1/2015
[/TD]
[TD]3/31/2015
[/TD]
[TD]
[/TD]
[TD]
[/TD]
[TD]
[/TD]
[TD]
[/TD]
[TD]ENGG-P
[/TD]
[TD]ENGG-P
[/TD]
[/TR]
</tbody>[/TABLE]

[TABLE="class: grid, width: 746"]
<colgroup><col><col span="6"></colgroup><tbody>[TR]
[TD][/TD]
[TD]OCT[/TD]
[TD]NOV[/TD]
[TD]DEC[/TD]
[TD]JAN[/TD]
[TD="align: right"]FEB[/TD]
[TD="align: right"]MAR[/TD]
[/TR]
[TR]
[TD]VP[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD="align: right"]1[/TD]
[TD="align: right"]1[/TD]
[/TR]
[TR]
[TD]AVP[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD="align: right"]1[/TD]
[TD="align: right"]1[/TD]
[TD][/TD]
[/TR]
[TR]
[TD]SRMNG[/TD]
[TD="align: right"]1[/TD]
[TD="align: right"]1[/TD]
[TD="align: right"]1[/TD]
[TD="align: right"]1[/TD]
[TD="align: right"]1[/TD]
[TD="align: right"]1[/TD]
[/TR]
[TR]
[TD]INTERN[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD="align: right"]5[/TD]
[TD="align: right"]5[/TD]
[TD="align: right"]5[/TD]
[/TR]
[TR]
[TD]ENGG[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD="align: right"]1[/TD]
[TD="align: right"]1[/TD]
[/TR]
</tbody>[/TABLE]
 

Excel Facts

How to fill five years of quarters?
Type 1Q-2023 in a cell. Grab the fill handle and drag down or right. After 4Q-2023, Excel will jump to 1Q-2024. Dash can be any character.
Results M1:S6


[TABLE="width: 448"]


<colgroup><col width="64" style="width: 48pt;" span="7">
<tbody>[TR]

[TD="class: xl65, width: 64, bgcolor: transparent"] [/TD]

[TD="class: xl65, width: 64, bgcolor: transparent"]OCT[/TD]

[TD="class: xl65, width: 64, bgcolor: transparent"]NOV[/TD]

[TD="class: xl65, width: 64, bgcolor: transparent"]DEC[/TD]

[TD="class: xl65, width: 64, bgcolor: transparent"]JAN[/TD]

[TD="class: xl65, width: 64, bgcolor: transparent"]FEB[/TD]

[TD="class: xl65, width: 64, bgcolor: transparent"]MAR[/TD]

[/TR]

[TR]

[TD="class: xl65, bgcolor: transparent"]VP[/TD]

[TD="class: xl65, bgcolor: transparent, align: right"]0[/TD]

[TD="class: xl65, bgcolor: transparent, align: right"]0[/TD]

[TD="class: xl65, bgcolor: transparent, align: right"]0[/TD]

[TD="class: xl65, bgcolor: transparent, align: right"]0[/TD]

[TD="class: xl65, bgcolor: transparent, align: right"]1[/TD]

[TD="class: xl65, bgcolor: transparent, align: right"]1[/TD]

[/TR]

[TR]

[TD="class: xl65, bgcolor: transparent"]AVP[/TD]

[TD="class: xl65, bgcolor: transparent, align: right"]0[/TD]

[TD="class: xl65, bgcolor: transparent, align: right"]0[/TD]

[TD="class: xl65, bgcolor: transparent, align: right"]0[/TD]

[TD="class: xl65, bgcolor: transparent, align: right"]1[/TD]

[TD="class: xl65, bgcolor: transparent, align: right"]1[/TD]

[TD="class: xl65, bgcolor: transparent, align: right"]0[/TD]

[/TR]

[TR]

[TD="class: xl65, bgcolor: transparent"]SRMNG[/TD]

[TD="class: xl65, bgcolor: transparent, align: right"]1[/TD]

[TD="class: xl65, bgcolor: transparent, align: right"]1[/TD]

[TD="class: xl65, bgcolor: transparent, align: right"]1[/TD]

[TD="class: xl65, bgcolor: transparent, align: right"]1[/TD]

[TD="class: xl65, bgcolor: transparent, align: right"]1[/TD]

[TD="class: xl65, bgcolor: transparent, align: right"]1[/TD]

[/TR]

[TR]

[TD="class: xl65, bgcolor: transparent"]INTERN[/TD]

[TD="class: xl65, bgcolor: transparent, align: right"]0[/TD]

[TD="class: xl65, bgcolor: transparent, align: right"]0[/TD]

[TD="class: xl65, bgcolor: transparent, align: right"]0[/TD]

[TD="class: xl65, bgcolor: transparent, align: right"]5[/TD]

[TD="class: xl65, bgcolor: transparent, align: right"]5[/TD]

[TD="class: xl65, bgcolor: transparent, align: right"]5[/TD]

[/TR]

[TR]

[TD="class: xl65, bgcolor: transparent"]ENGG[/TD]

[TD="class: xl65, bgcolor: transparent, align: right"]0[/TD]

[TD="class: xl65, bgcolor: transparent, align: right"]0[/TD]

[TD="class: xl65, bgcolor: transparent, align: right"]0[/TD]

[TD="class: xl65, bgcolor: transparent, align: right"]0[/TD]

[TD="class: xl65, bgcolor: transparent, align: right"]1[/TD]

[TD="class: xl65, bgcolor: transparent, align: right"]0[/TD]

[/TR]


</tbody>[/TABLE]

N2, confirmed with CONTROL+SHIFT+ENTER, copied across and down:

=SUM(IF(FREQUENCY(IF(LEFT(INDEX($F$2:$K$16,0,MATCH(N$1,$F$1:$K$1,0)),LEN($M2))=$M2,MATCH("~"&$A$2:$A$16,$A$2:$A$16&"",0)),ROW($A$2:$A$16)-ROW($A$2)+1)>0,1))

Hope this helps!
 
Upvote 0
Hi Domenic,

Thank your very much for your help. You made my day...solution worked like charm...:)
 
Upvote 0

Forum statistics

Threads
1,223,268
Messages
6,171,100
Members
452,379
Latest member
IainTru

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