Formula help

wildbio

New Member
Joined
Sep 14, 2011
Messages
6
I need a formula that will return a value in a different column but the same row. ie. if any cell in column A contains the text "YES", return the contents (text) in the corresponding row of column C. All rows of column A will be filled and only some of column C.
 

Excel Facts

Ambidextrous Undo
Undo last command with Ctrl+Z or Alt+Backspace. If you use the Undo icon in the QAT, open the drop-down arrow to undo up to 100 steps.
I need a formula to scan two columns that looks something like this
No X
Yes X
Yes
No X
Yes X
I need it to return the number 2 because there are two Yes's in the first column that have corresponding Xs in the second column.
There is no way I would have guessed that is what you wanted from your previous descriptions. For future question you might ask in the future... including a before and after example along with your description is always helpful. Assuming your two columns are A and C, give this formula a try...

=SUMPRODUCT(('Sheet 1'!A1:A1000="yes")*('Sheet 1'!C1:C1000="x"))

Change the two ranges to suit your data and make them large enough to cover all your present and possible future data (the row ranges for both need to be identical).
 
Upvote 0
Another way:

<b>Excel 2007</b><table cellpadding="2.5px" rules="all" style=";background-color: #FFFFFF;border: 1px solid;border-collapse: collapse; border-color: #A6AAB6"><colgroup><col width="25px" style="background-color: #E0E0F0" /><col /><col /><col /><col /><col /><col /></colgroup><thead><tr style=" background-color: #E0E0F0;text-align: center;color: #161120"><th></th><th>A</th><th>B</th><th>C</th><th>D</th><th>E</th><th>F</th></tr></thead><tbody><tr ><td style="color: #161120;text-align: center;">1</td><td style="text-align: center;;">Col01</td><td style="text-align: center;;">Col02</td><td style="text-align: center;;">Col03</td><td style="text-align: center;;"></td><td style="text-align: center;background-color: #C5D9F1;;"></td><td style="text-align: center;background-color: #C5D9F1;;">Result</td></tr><tr ><td style="color: #161120;text-align: center;">2</td><td style="text-align: center;background-color: #C5D9F1;;">Yes</td><td style="text-align: center;background-color: #C5D9F1;;"></td><td style="text-align: center;background-color: #C5D9F1;;">Name27</td><td style="text-align: center;;"></td><td style="text-align: center;background-color: #C5D9F1;;">Yes</td><td style="text-align: center;background-color: #C5D9F1;;">4</td></tr><tr ><td style="color: #161120;text-align: center;">3</td><td style="text-align: center;;">Data</td><td style="text-align: center;;"></td><td style="text-align: center;;">Name55</td><td style="text-align: center;;"></td><td style="text-align: center;background-color: #C5D9F1;;">Name27</td><td style="text-align: center;background-color: #C5D9F1;;"></td></tr><tr ><td style="color: #161120;text-align: center;">4</td><td style="text-align: center;;">Data</td><td style="text-align: center;;"></td><td style="text-align: center;;">Name10</td><td style="text-align: center;;"></td><td style="text-align: center;;"></td><td style="text-align: center;;"></td></tr><tr ><td style="color: #161120;text-align: center;">5</td><td style="text-align: center;;">Data</td><td style="text-align: center;;"></td><td style="text-align: center;;"></td><td style="text-align: center;;"></td><td style="text-align: center;;"></td><td style="text-align: center;;"></td></tr><tr ><td style="color: #161120;text-align: center;">6</td><td style="text-align: center;background-color: #C5D9F1;;">Yes</td><td style="text-align: center;background-color: #C5D9F1;;"></td><td style="text-align: center;background-color: #C5D9F1;;">Name27</td><td style="text-align: center;;"></td><td style="text-align: center;;"></td><td style="text-align: center;;"></td></tr><tr ><td style="color: #161120;text-align: center;">7</td><td style="text-align: center;;">No</td><td style="text-align: center;;"></td><td style="text-align: center;;">Name28</td><td style="text-align: center;;"></td><td style="text-align: center;;"></td><td style="text-align: center;;"></td></tr><tr ><td style="color: #161120;text-align: center;">8</td><td style="text-align: center;;">No</td><td style="text-align: center;;"></td><td style="text-align: center;;"></td><td style="text-align: center;;"></td><td style="text-align: center;;"></td><td style="text-align: center;;"></td></tr><tr ><td style="color: #161120;text-align: center;">9</td><td style="text-align: center;;">No</td><td style="text-align: center;;"></td><td style="text-align: center;;"></td><td style="text-align: center;;"></td><td style="text-align: center;;"></td><td style="text-align: center;;"></td></tr><tr ><td style="color: #161120;text-align: center;">10</td><td style="text-align: center;;">No</td><td style="text-align: center;;"></td><td style="text-align: center;;">Name32</td><td style="text-align: center;;"></td><td style="text-align: center;;"></td><td style="text-align: center;;"></td></tr><tr ><td style="color: #161120;text-align: center;">11</td><td style="text-align: center;;">Yes</td><td style="text-align: center;;"></td><td style="text-align: center;;"></td><td style="text-align: center;;"></td><td style="text-align: center;;"></td><td style="text-align: center;;"></td></tr><tr ><td style="color: #161120;text-align: center;">12</td><td style="text-align: center;background-color: #C5D9F1;;">Yes</td><td style="text-align: center;background-color: #C5D9F1;;"></td><td style="text-align: center;background-color: #C5D9F1;;">Name27</td><td style="text-align: center;;"></td><td style="text-align: center;;"></td><td style="text-align: center;;"></td></tr><tr ><td style="color: #161120;text-align: center;">13</td><td style="text-align: center;;">Yes</td><td style="text-align: center;;"></td><td style="text-align: center;;">Name88</td><td style="text-align: center;;"></td><td style="text-align: center;;"></td><td style="text-align: center;;"></td></tr><tr ><td style="color: #161120;text-align: center;">14</td><td style="text-align: center;;">No</td><td style="text-align: center;;"></td><td style="text-align: center;;">Name62</td><td style="text-align: center;;"></td><td style="text-align: center;;"></td><td style="text-align: center;;"></td></tr><tr ><td style="color: #161120;text-align: center;">15</td><td style="text-align: center;;">No</td><td style="text-align: center;;"></td><td style="text-align: center;;">Name19</td><td style="text-align: center;;"></td><td style="text-align: center;;"></td><td style="text-align: center;;"></td></tr><tr ><td style="color: #161120;text-align: center;">16</td><td style="text-align: center;;">Data</td><td style="text-align: center;;"></td><td style="text-align: center;;">Name26</td><td style="text-align: center;;"></td><td style="text-align: center;;"></td><td style="text-align: center;;"></td></tr><tr ><td style="color: #161120;text-align: center;">17</td><td style="text-align: center;;">Yes</td><td style="text-align: center;;"></td><td style="text-align: center;;"></td><td style="text-align: center;;"></td><td style="text-align: center;;"></td><td style="text-align: center;;"></td></tr><tr ><td style="color: #161120;text-align: center;">18</td><td style="text-align: center;background-color: #C5D9F1;;">Yes</td><td style="text-align: center;background-color: #C5D9F1;;"></td><td style="text-align: center;background-color: #C5D9F1;;">Name27</td><td style="text-align: center;;"></td><td style="text-align: center;;"></td><td style="text-align: center;;"></td></tr><tr ><td style="color: #161120;text-align: center;">19</td><td style="text-align: center;;">Yes</td><td style="text-align: center;;"></td><td style="text-align: center;;"></td><td style="text-align: center;;"></td><td style="text-align: center;;"></td><td style="text-align: center;;"></td></tr><tr ><td style="color: #161120;text-align: center;">20</td><td style="text-align: center;;">Data</td><td style="text-align: center;;"></td><td style="text-align: center;;">Name85</td><td style="text-align: center;;"></td><td style="text-align: center;;"></td><td style="text-align: center;;"></td></tr><tr ><td style="color: #161120;text-align: center;">21</td><td style="text-align: center;;"></td><td style="text-align: center;;"></td><td style="text-align: center;;"></td><td style="text-align: center;;"></td><td style="text-align: center;;"></td><td style="text-align: center;;"></td></tr><tr ><td style="color: #161120;text-align: center;">22</td><td style="text-align: center;;">******</td><td style="text-align: center;;">******</td><td style="text-align: center;;">******</td><td style="text-align: center;;">******</td><td style="text-align: center;;">******</td><td style="text-align: center;;">******</td></tr></tbody></table><p style="width:3.6em;font-weight:bold;margin:0;padding:0.2em 0.6em 0.2em 0.5em;border: 1px solid #A6AAB6;border-top:none;text-align: center;background-color: #E0E0F0;color: #161120">Sheet5</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>Worksheet 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: #A6AAB6"><thead><tr style=" background-color: #E0E0F0;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: #E0E0F0;color: #161120">F2</th><td style="text-align:left">=SUMPRODUCT(<font color="Blue">--(<font color="Red">A2:A20&C2:D20=E2&E3</font>)</font>)</td></tr></tbody></table></td></tr></table><br />
Markmzz
 
Upvote 0
on Markzzz sample but with Arrary formula
<b>Excel 2007</b><table cellpadding="2.5px" rules="all" style=";background-color: #FFFFFF;border: 1px solid;border-collapse: collapse; border-color: #A6AAB6"><colgroup><col width="25px" style="background-color: #E0E0F0" /><col /><col /><col /><col /><col /><col /></colgroup><thead><tr style=" background-color: #E0E0F0;text-align: center;color: #161120"><th></th><th>A</th><th>B</th><th>C</th><th>D</th><th>E</th><th>F</th></tr></thead><tbody><tr ><td style="color: #161120;text-align: center;">1</td><td style="text-align: center;background-color: #FFFFFF;;">Col01</td><td style="text-align: center;background-color: #FFFFFF;;">Col02</td><td style="text-align: center;background-color: #FFFFFF;;">Col03</td><td style="text-align: center;background-color: #FFFFFF;;"></td><td style="text-align: center;background-color: #C5D9F1;;"></td><td style="text-align: center;border-right: 1px solid black;background-color: #C5D9F1;;">Result</td></tr><tr ><td style="color: #161120;text-align: center;">2</td><td style="text-align: center;background-color: #C5D9F1;;">Yes</td><td style="text-align: center;background-color: #C5D9F1;;"></td><td style="text-align: center;background-color: #C5D9F1;;">Name27</td><td style="text-align: center;background-color: #FFFFFF;;"></td><td style="text-align: center;background-color: #C5D9F1;;">Yes</td><td style="text-align: center;background-color: #C5D9F1;;">4</td></tr><tr ><td style="color: #161120;text-align: center;">3</td><td style="text-align: center;background-color: #FFFFFF;;">Data</td><td style="text-align: center;background-color: #FFFFFF;;"></td><td style="text-align: center;background-color: #FFFFFF;;">Name55</td><td style="text-align: center;background-color: #FFFFFF;;"></td><td style="text-align: center;background-color: #C5D9F1;;">Name27</td><td style="text-align: center;border-right: 1px solid black;background-color: #C5D9F1;;"></td></tr><tr ><td style="color: #161120;text-align: center;">4</td><td style="text-align: center;background-color: #FFFFFF;;">Data</td><td style="text-align: center;background-color: #FFFFFF;;"></td><td style="text-align: center;background-color: #FFFFFF;;">Name10</td><td style="text-align: center;background-color: #FFFFFF;;"></td><td style="text-align: center;background-color: #FFFFFF;;"></td><td style="text-align: center;border-right: 1px solid black;background-color: #FFFFFF;;"></td></tr><tr ><td style="color: #161120;text-align: center;">5</td><td style="text-align: center;background-color: #FFFFFF;;">Data</td><td style="text-align: center;background-color: #FFFFFF;;"></td><td style="text-align: center;background-color: #FFFFFF;;"></td><td style="text-align: center;background-color: #FFFFFF;;"></td><td style="text-align: center;background-color: #FFFFFF;;"></td><td style="text-align: center;border-right: 1px solid black;background-color: #FFFFFF;;"></td></tr><tr ><td style="color: #161120;text-align: center;">6</td><td style="text-align: center;background-color: #C5D9F1;;">Yes</td><td style="text-align: center;background-color: #C5D9F1;;"></td><td style="text-align: center;background-color: #C5D9F1;;">Name27</td><td style="text-align: center;background-color: #FFFFFF;;"></td><td style="text-align: center;background-color: #FFFFFF;;"></td><td style="text-align: center;border-right: 1px solid black;background-color: #FFFFFF;;"></td></tr><tr ><td style="color: #161120;text-align: center;">7</td><td style="text-align: center;background-color: #FFFFFF;;">No</td><td style="text-align: center;background-color: #FFFFFF;;"></td><td style="text-align: center;background-color: #FFFFFF;;">Name28</td><td style="text-align: center;background-color: #FFFFFF;;"></td><td style="text-align: center;background-color: #FFFFFF;;"></td><td style="text-align: center;border-right: 1px solid black;background-color: #FFFFFF;;"></td></tr><tr ><td style="color: #161120;text-align: center;">8</td><td style="text-align: center;background-color: #FFFFFF;;">No</td><td style="text-align: center;background-color: #FFFFFF;;"></td><td style="text-align: center;background-color: #FFFFFF;;"></td><td style="text-align: center;background-color: #FFFFFF;;"></td><td style="text-align: center;background-color: #FFFFFF;;"></td><td style="text-align: center;border-right: 1px solid black;background-color: #FFFFFF;;"></td></tr><tr ><td style="color: #161120;text-align: center;">9</td><td style="text-align: center;background-color: #FFFFFF;;">No</td><td style="text-align: center;background-color: #FFFFFF;;"></td><td style="text-align: center;background-color: #FFFFFF;;"></td><td style="text-align: center;background-color: #FFFFFF;;"></td><td style="text-align: center;background-color: #FFFFFF;;"></td><td style="text-align: center;border-right: 1px solid black;background-color: #FFFFFF;;"></td></tr><tr ><td style="color: #161120;text-align: center;">10</td><td style="text-align: center;background-color: #FFFFFF;;">No</td><td style="text-align: center;background-color: #FFFFFF;;"></td><td style="text-align: center;background-color: #FFFFFF;;">Name32</td><td style="text-align: center;background-color: #FFFFFF;;"></td><td style="text-align: center;background-color: #FFFFFF;;"></td><td style="text-align: center;border-right: 1px solid black;background-color: #FFFFFF;;"></td></tr><tr ><td style="color: #161120;text-align: center;">11</td><td style="text-align: center;background-color: #FFFFFF;;">Yes</td><td style="text-align: center;background-color: #FFFFFF;;"></td><td style="text-align: center;background-color: #FFFFFF;;"></td><td style="text-align: center;background-color: #FFFFFF;;"></td><td style="text-align: center;background-color: #FFFFFF;;"></td><td style="text-align: center;border-right: 1px solid black;background-color: #FFFFFF;;"></td></tr><tr ><td style="color: #161120;text-align: center;">12</td><td style="text-align: center;background-color: #C5D9F1;;">Yes</td><td style="text-align: center;background-color: #C5D9F1;;"></td><td style="text-align: center;background-color: #C5D9F1;;">Name27</td><td style="text-align: center;background-color: #FFFFFF;;"></td><td style="text-align: center;background-color: #FFFFFF;;"></td><td style="text-align: center;border-right: 1px solid black;background-color: #FFFFFF;;"></td></tr><tr ><td style="color: #161120;text-align: center;">13</td><td style="text-align: center;background-color: #FFFFFF;;">Yes</td><td style="text-align: center;background-color: #FFFFFF;;"></td><td style="text-align: center;background-color: #FFFFFF;;">Name88</td><td style="text-align: center;background-color: #FFFFFF;;"></td><td style="text-align: center;background-color: #FFFFFF;;"></td><td style="text-align: center;border-right: 1px solid black;background-color: #FFFFFF;;"></td></tr><tr ><td style="color: #161120;text-align: center;">14</td><td style="text-align: center;background-color: #FFFFFF;;">No</td><td style="text-align: center;background-color: #FFFFFF;;"></td><td style="text-align: center;background-color: #FFFFFF;;">Name62</td><td style="text-align: center;background-color: #FFFFFF;;"></td><td style="text-align: center;background-color: #FFFFFF;;"></td><td style="text-align: center;border-right: 1px solid black;background-color: #FFFFFF;;"></td></tr><tr ><td style="color: #161120;text-align: center;">15</td><td style="text-align: center;background-color: #FFFFFF;;">No</td><td style="text-align: center;background-color: #FFFFFF;;"></td><td style="text-align: center;background-color: #FFFFFF;;">Name19</td><td style="text-align: center;background-color: #FFFFFF;;"></td><td style="text-align: center;background-color: #FFFFFF;;"></td><td style="text-align: center;border-right: 1px solid black;background-color: #FFFFFF;;"></td></tr><tr ><td style="color: #161120;text-align: center;">16</td><td style="text-align: center;background-color: #FFFFFF;;">Data</td><td style="text-align: center;background-color: #FFFFFF;;"></td><td style="text-align: center;background-color: #FFFFFF;;">Name26</td><td style="text-align: center;background-color: #FFFFFF;;"></td><td style="text-align: center;background-color: #FFFFFF;;"></td><td style="text-align: center;border-right: 1px solid black;background-color: #FFFFFF;;"></td></tr><tr ><td style="color: #161120;text-align: center;">17</td><td style="text-align: center;background-color: #FFFFFF;;">Yes</td><td style="text-align: center;background-color: #FFFFFF;;"></td><td style="text-align: center;background-color: #FFFFFF;;"></td><td style="text-align: center;background-color: #FFFFFF;;"></td><td style="text-align: center;background-color: #FFFFFF;;"></td><td style="text-align: center;border-right: 1px solid black;background-color: #FFFFFF;;"></td></tr><tr ><td style="color: #161120;text-align: center;">18</td><td style="text-align: center;background-color: #C5D9F1;;">Yes</td><td style="text-align: center;background-color: #C5D9F1;;"></td><td style="text-align: center;background-color: #C5D9F1;;">Name27</td><td style="text-align: center;background-color: #FFFFFF;;"></td><td style="text-align: center;background-color: #FFFFFF;;"></td><td style="text-align: center;border-right: 1px solid black;background-color: #FFFFFF;;"></td></tr><tr ><td style="color: #161120;text-align: center;">19</td><td style="text-align: center;background-color: #FFFFFF;;">Yes</td><td style="text-align: center;background-color: #FFFFFF;;"></td><td style="text-align: center;background-color: #FFFFFF;;"></td><td style="text-align: center;background-color: #FFFFFF;;"></td><td style="text-align: center;background-color: #FFFFFF;;"></td><td style="text-align: center;border-right: 1px solid black;background-color: #FFFFFF;;"></td></tr><tr ><td style="color: #161120;text-align: center;">20</td><td style="text-align: center;border-bottom: 1px solid black;background-color: #FFFFFF;;">Data</td><td style="text-align: center;border-bottom: 1px solid black;background-color: #FFFFFF;;"></td><td style="text-align: center;border-bottom: 1px solid black;background-color: #FFFFFF;;">Name85</td><td style="text-align: center;border-bottom: 1px solid black;background-color: #FFFFFF;;"></td><td style="text-align: right;border-bottom: 1px solid black;background-color: #FFFFFF;;"></td><td style="text-align: right;border-right: 1px solid black;border-bottom: 1px solid black;background-color: #FFFFFF;;"></td></tr></tbody></table><p style="width:3.6em;font-weight:bold;margin:0;padding:0.2em 0.6em 0.2em 0.5em;border: 1px solid #A6AAB6;border-top:none;text-align: center;background-color: #E0E0F0;color: #161120">Sheet5</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: #A6AAB6"><thead><tr style=" background-color: #E0E0F0;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: #E0E0F0;color: #161120">F2</th><td style="text-align:left">{=SUM(<font color="Blue">IF(<font color="Red">A2:A20=E2,IF(<font color="Green">C2:C20=E3,1</font>)</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 />
 
Upvote 0

Forum statistics

Threads
1,224,609
Messages
6,179,879
Members
452,948
Latest member
Dupuhini

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