Countifs ignoring duplicate dates in specific range

-=NO=-

New Member
Joined
May 9, 2011
Messages
27
Office Version
  1. 365
  2. 2019
Platform
  1. Windows
Hello Guys;

I do appreciate your help to count the number of codes in each year ignoring the duplicates dates in this selected year

I used that formula but it's not ignoring duplicates

Code:
=COUNTIFS(Data!$B$2:$B$10000,B2,Data!$A$2:$A$10000,">=1/1/2012",Data!$A$2:$A$10000,"<1/1/2013")

A (Date)B (Code)
29-06-091NACHLRD
29-06-091HYDRCAC
20-06-101ACTCAC
29-06-121MTLPRBNB
29-06-091BNZYLALC
29-06-091NAEDTA
29-06-091PEG400
29-06-091ETHNL96
29-06-091DMNNTL
02-06-131NACHLRD
29-06-091NAACTTHD
29-06-091ETHNL96
30-06-092AMVAR05TR
12-07-121MTLPRBNB
12-07-131NAMTBSLF
16-07-141NACHLRD
02-08-151LCOVNCA
10-08-092AMVAR05TR
10-08-092AMVAR05TR
10-08-192AMVAR05TR

<colgroup><col><col></colgroup><tbody>
</tbody>

<tbody>
</tbody>
 
OK Dante.

I have two sheets, the second is the target sheet, what i need is a formula in each cell to count the no. of code that repeated in specific year such as 2012

Code2012201320142015
1DCTXLTRHD11
1DXRBCNHCL112
1ETPSD11

<tbody>
</tbody>

the first one, is containing the data

CodeDate
1DXRBCNHCL2/1/2013
1DCTXLTRHD1/5/2012
1DXRBCNHCL2/1/2012
1ETPSD10/7/2015
1DCTXLTRHD1/5/2012
1ETPSD2/1/2012
1ETPSD2/1/2012
1DXRBCNHCL2/1/2015
1DCTXLTRHD1/9/2015
1DXRBCNHCL22/10/2015

<tbody>
</tbody>

I hope this is clear now, and thanks again


Then try the following array formula.

<table style="font-family:Arial; font-size:12pt; border-style: groove ;border-color:#0000FF;background-color:#fffcf9; color:#000000; "><tr><td ><b>Sheet1</b></td></tr></table><table style="font-family:Arial; font-size:12pt; border-style: groove ;border-color:#0000FF;background-color:#fffcf9; color:#000000; "><tr><td ><b>Sheet</b></td></tr></table>
<table border="1" cellspacing="0" style="font-family:Calibri,Arial; font-size:11pt; background-color:#ffffff; "> <colgroup><col style="font-weight:bold; width:30px; " /><col style="width:109.31px;" /><col style="width:97.9px;" /></colgroup><tr style="background-color:#cacaca; text-align:center; font-weight:bold; font-size:8pt; "><td > </td><td >A</td><td >B</td></tr><tr style="height:19px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >1</td><td style="background-color:#ffff00; font-weight:bold; text-align:center; ">Code</td><td style="background-color:#ffff00; font-weight:bold; text-align:center; ">Date</td></tr><tr style="height:19px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >2</td><td >1DXRBCNHCL</td><td style="text-align:right; ">02/01/2013</td></tr><tr style="height:19px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >3</td><td >1DCTXLTRHD</td><td style="text-align:right; ">01/05/2012</td></tr><tr style="height:19px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >4</td><td >1DXRBCNHCL</td><td style="text-align:right; ">02/01/2012</td></tr><tr style="height:19px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >5</td><td >1ETPSD</td><td style="text-align:right; ">10/07/2015</td></tr><tr style="height:19px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >6</td><td >1DCTXLTRHD</td><td style="text-align:right; ">01/05/2012</td></tr><tr style="height:19px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >7</td><td >1ETPSD</td><td style="text-align:right; ">02/01/2012</td></tr><tr style="height:19px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >8</td><td >1ETPSD</td><td style="text-align:right; ">02/01/2012</td></tr><tr style="height:19px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >9</td><td >1DXRBCNHCL</td><td style="text-align:right; ">02/01/2015</td></tr><tr style="height:19px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >10</td><td >1DCTXLTRHD</td><td style="text-align:right; ">01/09/2015</td></tr><tr style="height:19px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >11</td><td >1DXRBCNHCL</td><td style="text-align:right; ">22/10/2015</td></tr></table>

-----------
<table style="font-family:Arial; font-size:12pt; border-style: groove ;border-color:#0000FF;background-color:#fffcf9; color:#000000; "><tr><td ><b>Sheet2</b></td></tr></table>
<table border="1" cellspacing="0" style="font-family:Calibri,Arial; font-size:11pt; background-color:#ffffff; "> <colgroup><col style="font-weight:bold; width:30px; " /><col style="width:129.27px;" /><col style="width:76.04px;" /><col style="width:76.04px;" /><col style="width:76.04px;" /><col style="width:76.04px;" /></colgroup><tr style="background-color:#cacaca; text-align:center; font-weight:bold; font-size:8pt; "><td > </td><td >A</td><td >B</td><td >C</td><td >D</td><td >E</td></tr><tr style="height:19px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >1</td><td style="background-color:#ffff00; font-weight:bold; text-align:center; ">Code</td><td style="background-color:#ffff00; font-weight:bold; text-align:center; ">2012</td><td style="background-color:#ffff00; font-weight:bold; text-align:center; ">2013</td><td style="background-color:#ffff00; font-weight:bold; text-align:center; ">2014</td><td style="background-color:#ffff00; font-weight:bold; text-align:center; ">2015</td></tr><tr style="height:19px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >2</td><td >1DCTXLTRHD</td><td style="text-align:right; ">1</td><td style="text-align:right; ">0</td><td style="text-align:right; ">0</td><td style="text-align:right; ">1</td></tr><tr style="height:19px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >3</td><td >1DXRBCNHCL</td><td style="text-align:right; ">1</td><td style="text-align:right; ">1</td><td style="text-align:right; ">0</td><td style="text-align:right; ">2</td></tr><tr style="height:19px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >4</td><td >1ETPSD</td><td style="text-align:right; ">1</td><td style="text-align:right; ">0</td><td style="text-align:right; ">0</td><td style="text-align:right; ">1</td></tr></table><br /><table style="font-family:Arial; font-size:10pt; border-style: groove ;border-color:#00ff00;background-color:#fffcf9; color:#000000; "><tr><td ><b></b></td></tr><tr><td ><table border = "1" cellspacing="0" cellpadding="2" style="font-family:Arial; font-size:9pt;"><tr style="background-color:#cacaca; font-size:10pt;"><td >Cell</td><td >Formula</td></tr><tr><td >B2</td><td >{=SUM(IF(FREQUENCY(IF((Sheet1!$A$2:$A$11=$A2)*(YEAR(Sheet1!$B$2:$B$11)=B$1),Sheet1!$B$2:$B$11),Sheet1!$B$2:$B$11),1))}</td></tr></table></td></tr></table>


Array formulas
Entered with Ctrl+Shift+Enter. If entered correctly, Excel will surround with curly braces {}.
Note: Do not try and enter the {} manually yourself

Then copy to the right and then down.
 
Upvote 0

Excel Facts

Copy formula down without changing references
If you have =SUM(F2:F49) in F50; type Alt+' in F51 to copy =SUM(F2:F49) to F51, leaving the formula in edit mode. Change SUM to COUNT.

Forum statistics

Threads
1,213,546
Messages
6,114,251
Members
448,556
Latest member
peterhess2002

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