Using Table Arrays to extract unique data from table

cchampagne17

New Member
Joined
Jul 30, 2012
Messages
15
Good afternoon,
I'm trying to create an automatic table using an array function I found online... However when I tried to apply the formula to my table it finds an error. What I am trying to do is type in a date in cell C10, then the array function returns unique overall grades from that date.

The array formula I entered into E10 (and dragged down..) is..
=INDEX(Item, SMALL(IF(($C$10=Date)*(COUNTIF($E$9:E9,Grade)=0), ROW(Date)-MIN(ROW(Date))+1, ""), 1))

I did hold down Shift+CTRL when I hit enter when I modified the formula. I named B3:B8 "Date", as well as F3:F8 "Grade" for name references. I also made sure that the formula is linking the names and not the date function or whatnot.

If anyone can help me figure out what is wrong with the formula that would be extremely helpful. Thank you

Chris


Below is the table that I am referring to..


ABCDEFG
1
2DateCommentsYes TotalNo TotalOverall Grade
37/24/2014181162.07%
47/24/2014251660.98%
57/24/2014153231.91%
67/24/2014173334%
77/24/2014252352.08%
87/29/2014311468.89%
9
10SearchSearch Results
11
12
13

<tbody>
</tbody>
 

Some videos you may like

Excel Facts

Test for Multiple Conditions in IF?
Use AND(test, test, test, test) or OR(test, test, test, ...) as the logical_test argument of IF.

skywriter

Well-known Member
Joined
Feb 15, 2014
Messages
1,642
Let me know if this is what you are after.

<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 /><col /><col /></colgroup><thead><tr style=" background-color: #DAE7F5;text-align: center;color: #161120"><th></th><th>B</th><th>C</th><th>D</th><th>E</th><th>F</th><th>G</th></tr></thead><tbody><tr ><td style="color: #161120;text-align: center;">2</td><td style=";">Date</td><td style="text-align: center;;">Comments</td><td style=";">Yes Total</td><td style=";">No Total</td><td style=";">Overall Grade</td><td style="text-align: right;;"></td></tr><tr ><td style="color: #161120;text-align: center;">3</td><td style="text-align: right;;">7/24/2014</td><td style="text-align: center;;"></td><td style="text-align: right;;">18</td><td style="text-align: right;;">11</td><td style="text-align: right;;">62.07%</td><td style="text-align: right;;"></td></tr><tr ><td style="color: #161120;text-align: center;">4</td><td style="text-align: right;;">7/24/2014</td><td style="text-align: center;;"></td><td style="text-align: right;;">25</td><td style="text-align: right;;">16</td><td style="text-align: right;;">60.98%</td><td style="text-align: right;;"></td></tr><tr ><td style="color: #161120;text-align: center;">5</td><td style="text-align: right;;">7/24/2014</td><td style="text-align: center;;"></td><td style="text-align: right;;">15</td><td style="text-align: right;;">32</td><td style="text-align: right;;">31.91%</td><td style="text-align: right;;"></td></tr><tr ><td style="color: #161120;text-align: center;">6</td><td style="text-align: right;;">7/24/2014</td><td style="text-align: center;;"></td><td style="text-align: right;;">17</td><td style="text-align: right;;">33</td><td style="text-align: right;;">34%</td><td style="text-align: right;;"></td></tr><tr ><td style="color: #161120;text-align: center;">7</td><td style="text-align: right;;">7/24/2014</td><td style="text-align: center;;"></td><td style="text-align: right;;">25</td><td style="text-align: right;;">23</td><td style="text-align: right;;">52.08%</td><td style="text-align: right;;"></td></tr><tr ><td style="color: #161120;text-align: center;">8</td><td style="text-align: right;;">7/29/2014</td><td style="text-align: center;;"></td><td style="text-align: right;;">31</td><td style="text-align: right;;">14</td><td style="text-align: right;;">68.89%</td><td style="text-align: right;;"></td></tr><tr ><td style="color: #161120;text-align: center;">9</td><td style="text-align: right;;"></td><td style="text-align: center;;"></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;">10</td><td style=";">Search</td><td style="text-align: center;;">7/24/2014</td><td style=";">Search Results</td><td style="text-align: right;;">0.6207</td><td style="text-align: right;;"></td><td style="text-align: right;;"></td></tr><tr ><td style="color: #161120;text-align: center;">11</td><td style="text-align: right;;"></td><td style="text-align: center;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;">0.6098</td><td style="text-align: right;;"></td><td style="text-align: right;;"></td></tr><tr ><td style="color: #161120;text-align: center;">12</td><td style="text-align: right;;"></td><td style="text-align: center;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;">0.3191</td><td style="text-align: right;;"></td><td style="text-align: right;;"></td></tr><tr ><td style="color: #161120;text-align: center;">13</td><td style="text-align: right;;"></td><td style="text-align: center;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;">0.34</td><td style="text-align: right;;"></td><td style="text-align: right;;"></td></tr><tr ><td style="color: #161120;text-align: center;">14</td><td style="text-align: right;;"></td><td style="text-align: center;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;">0.5208</td><td style="text-align: right;;"></td><td style="text-align: right;;"></td></tr><tr ><td style="color: #161120;text-align: center;">15</td><td style="text-align: right;;"></td><td style="text-align: center;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;">#NUM!</td><td style="text-align: right;;"></td><td style="text-align: right;;"></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">Sheet35</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">E10</th><td style="text-align:left">{=INDEX(<font color="Blue">Grade, SMALL(<font color="Red">IF(<font color="Green">(<font color="Purple">$C$10=Date</font>)*(<font color="Purple">COUNTIF(<font color="Teal">$E$9:E9,Grade</font>)=0</font>), ROW(<font color="Purple">Date</font>)-MIN(<font color="Purple">ROW(<font color="Teal">Date</font>)</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 /><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>Workbook Defined Names</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">Name</th><th style="text-align:left">Refers To</th></tr></thead><tbody><tr><th width="10px" style=" background-color: #DAE7F5;color: #161120">Date</th><td style="text-align:left">=Sheet35!$B$3:$B$8</td></tr><tr><th width="10px" style=" background-color: #DAE7F5;color: #161120">Grade</th><td style="text-align:left">=Sheet35!$F$3:$F$8</td></tr></tbody></table></td></tr></table><br />
 

cchampagne17

New Member
Joined
Jul 30, 2012
Messages
15
Let me know if this is what you are after.

Excel 2010
BCDEFG
2DateCommentsYes TotalNo TotalOverall Grade
37/24/2014181162.07%
47/24/2014251660.98%
57/24/2014153231.91%
67/24/2014173334%
77/24/2014252352.08%
87/29/2014311468.89%
9
10Search7/24/2014Search Results0.6207
110.6098
120.3191
130.34
140.5208
15#NUM!

<colgroup><col style="width: 25pxpx"><col><col><col><col><col><col></colgroup><thead>
</thead><tbody>
</tbody>
Sheet35

Array Formulas
CellFormula
E10{=INDEX(Grade, SMALL(IF(($C$10=Date)*(COUNTIF($E$9:E9,Grade)=0), ROW(Date)-MIN(ROW(Date))+1, ""), 1))}

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

<tbody>
</tbody>

Workbook Defined Names
NameRefers To
Date=Sheet35!$B$3:$B$8
Grade=Sheet35!$F$3:$F$8

<thead>
</thead><tbody>
</tbody>

<tbody>
</tbody>


Yes! Worked great thank you!
 

Watch MrExcel Video

Forum statistics

Threads
1,109,411
Messages
5,528,617
Members
409,828
Latest member
99DodgeRam

This Week's Hot Topics

  • Change military grades into rank
    Afternoon all Need help with formula that will change military rank (i.e. 1, 2, 3 into Amn, A1C, SrA). Running IF formula that does not work...
  • VBA COUNTIF SOLUTION
    Hi The following are the errors spread across the several columns from E to Q ie. 13 columns across several sheets with more than 500 rows per...
  • INSERT ROW WITH SPECIFIS TEXT IN A COLUMN
    Hi All! How can identify that that the row to be inserted has to be inserted before 1st row with specific text in column F. If I record the...
  • Auto-Create a monthly Sign in sheet for preschool students
    The image below is what each page looks like. Above is space for the "Child Name" "Month" "Class" School days are obviously Monday-Friday but...
  • VBA vlookup multiple results
    Hi folks, Hopefully someone out there can help. I have a list to vlookup which works (ish). the lookup only picks up the first instance of the...
  • Extract values for earliest/latest times
    I am trying to put together a formula to get the earliest start time, the latest end time from column A for each person in Column B-F without the...
Top