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
[TABLE="width: 500"]
<tbody>[TR]
[TD]Code[/TD]
[TD]2012[/TD]
[TD]2013[/TD]
[TD]2014[/TD]
[TD]2015[/TD]
[/TR]
[TR]
[TD]1DCTXLTRHD[/TD]
[TD]1[/TD]
[TD][/TD]
[TD][/TD]
[TD]1[/TD]
[/TR]
[TR]
[TD]1DXRBCNHCL[/TD]
[TD]1[/TD]
[TD]1[/TD]
[TD][/TD]
[TD]2[/TD]
[/TR]
[TR]
[TD]1ETPSD[/TD]
[TD]1[/TD]
[TD][/TD]
[TD][/TD]
[TD]1[/TD]
[/TR]
</tbody>[/TABLE]
the first one, is containing the data
[TABLE="width: 500"]
<tbody>[TR]
[TD]Code[/TD]
[TD]Date[/TD]
[/TR]
[TR]
[TD]1DXRBCNHCL[/TD]
[TD]2/1/2013[/TD]
[/TR]
[TR]
[TD]1DCTXLTRHD[/TD]
[TD]1/5/2012[/TD]
[/TR]
[TR]
[TD]1DXRBCNHCL[/TD]
[TD]2/1/2012[/TD]
[/TR]
[TR]
[TD]1ETPSD[/TD]
[TD]10/7/2015[/TD]
[/TR]
[TR]
[TD]1DCTXLTRHD[/TD]
[TD]1/5/2012[/TD]
[/TR]
[TR]
[TD]1ETPSD[/TD]
[TD]2/1/2012[/TD]
[/TR]
[TR]
[TD]1ETPSD[/TD]
[TD]2/1/2012[/TD]
[/TR]
[TR]
[TD]1DXRBCNHCL[/TD]
[TD]2/1/2015[/TD]
[/TR]
[TR]
[TD]1DCTXLTRHD[/TD]
[TD]1/9/2015[/TD]
[/TR]
[TR]
[TD]1DXRBCNHCL[/TD]
[TD]22/10/2015[/TD]
[/TR]
</tbody>[/TABLE]
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.