count the unique values with conditions

chibimomo

New Member
Joined
Jul 25, 2013
Messages
5
Hi,

i'm having trouble trying to count the unique values/entries on column B (name) that has the ff conditions the date should be from july 1-5 for week one, week two ..etc, and team (red, etc..) as seen below.
if i need the count of unique names for the first week on red team it should return = 3. i tried using sumproduct(((date>=jul1)*(date<=jul5)),--(team="red").. but im stuck on how to only count the unique values.
please help. what formula should i use?

thank you.

1-Jul8-Jul
5-Jul12-Jul
TeamWeek OneWeek Two
Red3
Blue
datenameteamproduct
1-Julmikeredc
1-Juldavebluea
1-Julmikereda
1-Julpatreda
1-Julmikeredb
2-Julmikereda
2-Juldavebluea
2-Juldavebluea
2-Julcrisbluea
2-Julcrisblueb
3-Julmikeredb
4-Julbertredc
5-Julmikeredc

<tbody>
</tbody>
 

Some videos you may like

Excel Facts

Create a Pivot Table on a Map
If your data has zip codes, postal codes, or city names, select the data and use Insert, 3D Map. (Found to right of chart icons).

Andrew Poulsom

MrExcel MVP
Joined
Jul 21, 2002
Messages
73,092
Welcome to MrExcel.

Example:

<b>Excel 2010</b><table cellpadding="2.5px" rules="all" style=";background-color: #FFFFFF;border: 1px solid;border-collapse: collapse; border-color: #BBB"><colgroup><col width="25px" style="background-color: #DAE7F5" /><col /><col /><col /><col /></colgroup><thead><tr style=" background-color: #DAE7F5;text-align: center;color: #161120"><th></th><th>A</th><th>B</th><th>C</th><th>D</th></tr></thead><tbody><tr ><td style="color: #161120;text-align: center;">1</td><td style="text-align: right;;"></td><td style="text-align: right;;">01-Jul</td><td style="text-align: right;;">08-Jul</td><td style="text-align: right;;"></td></tr><tr ><td style="color: #161120;text-align: center;">2</td><td style="text-align: right;;"></td><td style="text-align: right;;">05-Jul</td><td style="text-align: right;;">12-Jul</td><td style="text-align: right;;"></td></tr><tr ><td style="color: #161120;text-align: center;">3</td><td style=";">Team</td><td style=";">Week One</td><td style=";">Week Two</td><td style="text-align: right;;"></td></tr><tr ><td style="color: #161120;text-align: center;">4</td><td style=";">Red</td><td style="text-align: right;;">3</td><td style="text-align: right;;">0</td><td style="text-align: right;;"></td></tr><tr ><td style="color: #161120;text-align: center;">5</td><td style=";">Blue</td><td style="text-align: right;;">2</td><td style="text-align: right;;">0</td><td style="text-align: right;;"></td></tr><tr ><td style="color: #161120;text-align: center;">6</td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td></tr><tr ><td style="color: #161120;text-align: center;">7</td><td style=";">date</td><td style=";">name</td><td style=";">team</td><td style=";">product</td></tr><tr ><td style="color: #161120;text-align: center;">8</td><td style="text-align: right;;">01-Jul</td><td style=";">mike</td><td style=";">red</td><td style=";">c</td></tr><tr ><td style="color: #161120;text-align: center;">9</td><td style="text-align: right;;">01-Jul</td><td style=";">dave</td><td style=";">blue</td><td style=";">a</td></tr><tr ><td style="color: #161120;text-align: center;">10</td><td style="text-align: right;;">01-Jul</td><td style=";">mike</td><td style=";">red</td><td style=";">a</td></tr><tr ><td style="color: #161120;text-align: center;">11</td><td style="text-align: right;;">01-Jul</td><td style=";">pat</td><td style=";">red</td><td style=";">a</td></tr><tr ><td style="color: #161120;text-align: center;">12</td><td style="text-align: right;;">01-Jul</td><td style=";">mike</td><td style=";">red</td><td style=";">b</td></tr><tr ><td style="color: #161120;text-align: center;">13</td><td style="text-align: right;;">02-Jul</td><td style=";">mike</td><td style=";">red</td><td style=";">a</td></tr><tr ><td style="color: #161120;text-align: center;">14</td><td style="text-align: right;;">02-Jul</td><td style=";">dave</td><td style=";">blue</td><td style=";">a</td></tr><tr ><td style="color: #161120;text-align: center;">15</td><td style="text-align: right;;">02-Jul</td><td style=";">dave</td><td style=";">blue</td><td style=";">a</td></tr><tr ><td style="color: #161120;text-align: center;">16</td><td style="text-align: right;;">02-Jul</td><td style=";">cris</td><td style=";">blue</td><td style=";">a</td></tr><tr ><td style="color: #161120;text-align: center;">17</td><td style="text-align: right;;">02-Jul</td><td style=";">cris</td><td style=";">blue</td><td style=";">b</td></tr><tr ><td style="color: #161120;text-align: center;">18</td><td style="text-align: right;;">03-Jul</td><td style=";">mike</td><td style=";">red</td><td style=";">b</td></tr><tr ><td style="color: #161120;text-align: center;">19</td><td style="text-align: right;;">04-Jul</td><td style=";">bert</td><td style=";">red</td><td style=";">c</td></tr><tr ><td style="color: #161120;text-align: center;">20</td><td style="text-align: right;;">05-Jul</td><td style=";">mike</td><td style=";">red</td><td style=";">c</td></tr></tbody></table><p style="width:4.2em;font-weight:bold;margin:0;padding:0.2em 0.6em 0.2em 0.5em;border: 1px solid #BBB;border-top:none;text-align: center;background-color: #DAE7F5;color: #161120">Sheet13</p><br /><br /><table width="85%" cellpadding="2.5px" rules="all" style=";border: 2px solid black;border-collapse:collapse;padding: 0.4em;background-color: #FFFFFF" ><tr><td style="padding:6px" ><b>Array Formulas</b><table cellpadding="2.5px" width="100%" rules="all" style="border: 1px solid;text-align:center;background-color: #FFFFFF;border-collapse: collapse; border-color: #BBB"><thead><tr style=" background-color: #DAE7F5;color: #161120"><th width="10px">Cell</th><th style="text-align:left;padding-left:5px;">Formula</th></tr></thead><tbody><tr><th width="10px" style=" background-color: #DAE7F5;color: #161120">B4</th><td style="text-align:left">{=SUM(<font color="Blue">IF(<font color="Red">FREQUENCY(<font color="Green">IF(<font color="Purple">$A$8:$A$20>=B$1,IF(<font color="Teal">$A$8:$A$20<=B$2,IF(<font color="#FF00FF">$C$8:$C$20=$A4,MATCH(<font color="Navy">$B$8:$B$20,$B$8:$B$20,0</font>)</font>)</font>)</font>),ROW(<font color="Purple">$A$8:$A$20</font>)-ROW(<font color="Purple">$A$8</font>)+1</font>),1</font>)</font>)}</td></tr></tbody></table><b>Entered with Ctrl+Shift+Enter.</b> If entered correctly, Excel will surround with curly braces {}.
<b>Note: Do not try and enter the {} manually yourself</b></td></tr></table><br />
 

chibimomo

New Member
Joined
Jul 25, 2013
Messages
5
Oh my! Thank you very much sir! :) thank you! i will study the formula you gave to better understand it.
again thank you very much. your a life saver.:biggrin:
 

raj2206

Board Regular
Joined
Jul 23, 2012
Messages
213
Hey Thanks for Writing!!

Another alternative if u like :)

=SUM(IFERROR(1/COUNTIF($B$8:$B$20,IF(IF(IF(($A$8:$A$20>=B$1)*($A$8:$A$20<=B$2)*($C$8:$C$20=$A4),MATCH($B$8:$B$20,$B$8:$B$20,0)),ROW($A$8:$A$20)-ROW($A$8)+1),$B$8:$B$20)),0))


Please make sure you press Control + Shift + Enter while entering the formula.

Thanks/Raj
 

chibimomo

New Member
Joined
Jul 25, 2013
Messages
5
Hey Thanks for Writing!!

Another alternative if u like :)

=SUM(IFERROR(1/COUNTIF($B$8:$B$20,IF(IF(IF(($A$8:$A$20>=B$1)*($A$8:$A$20<=B$2)*($C$8:$C$20=$A4),MATCH($B$8:$B$20,$B$8:$B$20,0)),ROW($A$8:$A$20)-ROW($A$8)+1),$B$8:$B$20)),0))


Please make sure you press Control + Shift + Enter while entering the formula.

Thanks/Raj
Hi Raj, Im a bit confuse.. i was trying to understand the formula you gave, but i couldn't follow the 2nd "IF" whats the "ROW" function for? sorry for the trouble but can you explain the formula to me? thank you.
 

Watch MrExcel Video

Forum statistics

Threads
1,099,330
Messages
5,467,976
Members
406,561
Latest member
Grappledog

This Week's Hot Topics

Top