OR operator with Sumproduct or {sum()}

lionelnz

Well-known Member
Joined
Apr 6, 2006
Messages
571
I have been trying to resolve this problem for months.

I would like to have a formula that produces a date code (format ddmmyyyy00) in J col based on "y" criteria in H col OR I col. At the moment I get it to work by using a helper cell with IF(OR) formula & this works. Ideally I want one formula in J col & do away with helper cell.

See below TIA.:)

Excel 2003<table rules="all" style=";background-color: #FFFFFF;border: 1px solid;border-collapse: collapse; border-color: #A6AAB6" cellpadding="2.5px"><colgroup><col style="background-color: #E0E0F0" width="25px"><col><col><col><col><col><col></colgroup><thead><tr style=" background-color: #E0E0F0;text-align: center;color: #161120"><th>
</th><th>A</th><th>E</th><th>H</th><th>I</th><th>J</th><th>O</th></tr></thead><tbody><tr><td style="color: #161120;text-align: center;">2</td><td style="font-weight: bold;text-align: center;border-top: 1px solid black;border-right: 1px solid black;border-bottom: 1px solid black;border-left: 1px solid black;;">Date</td><td style="font-weight: bold;text-align: center;border-top: 1px solid black;border-right: 1px solid black;border-bottom: 1px solid black;border-left: 1px solid black;;">Description</td><td style="font-weight: bold;text-align: center;border-top: 1px solid black;border-right: 1px solid black;border-bottom: 1px solid black;border-left: 1px solid black;;">Liquid Sample taken</td><td style="font-weight: bold;text-align: center;border-top: 1px solid black;border-right: 1px solid black;border-bottom: 1px solid black;border-left: 1px solid black;;">Solid Sample taken</td><td style="font-weight: bold;text-align: center;border-top: 1px solid black;border-right: 1px solid black;border-bottom: 1px solid black;border-left: 1px solid black;;">Sample ID</td><td style="font-weight: bold;text-align: center;;">
</td></tr><tr><td style="color: #161120;text-align: center;">27</td><td style="font-weight: bold;text-align: center;border-top: 1px solid black;border-right: 1px solid black;border-bottom: 1px solid black;border-left: 1px solid black;;">25/01/12</td><td style="font-weight: bold;text-align: center;border-top: 1px solid black;border-right: 1px solid black;border-bottom: 1px solid black;border-left: 1px solid black;;">RS</td><td style="font-weight: bold;text-align: center;border-top: 1px solid black;border-right: 1px solid black;border-bottom: 1px solid black;border-left: 1px solid black;;">
</td><td style="font-weight: bold;text-align: center;border-top: 1px solid black;border-right: 1px solid black;border-bottom: 1px solid black;border-left: 1px solid black;;">
</td><td style="font-weight: bold;text-align: center;border-top: 1px solid black;border-right: 1px solid black;border-bottom: 1px solid black;border-left: 1px solid black;;">
</td><td style="font-weight: bold;text-align: center;border-left: 1px solid black;;">
</td></tr><tr><td style="color: #161120;text-align: center;">28</td><td style="font-weight: bold;text-align: center;border-top: 1px solid black;border-right: 1px solid black;border-bottom: 1px solid black;border-left: 1px solid black;;">27/01/12</td><td style="font-weight: bold;text-align: center;border-top: 1px solid black;border-right: 1px solid black;border-bottom: 1px solid black;border-left: 1px solid black;;">CP</td><td style="font-weight: bold;text-align: center;border-top: 1px solid black;border-right: 1px solid black;border-bottom: 1px solid black;border-left: 1px solid black;;">y</td><td style="font-weight: bold;text-align: center;border-top: 1px solid black;border-right: 1px solid black;border-bottom: 1px solid black;border-left: 1px solid black;;">y</td><td style="font-weight: bold;text-align: center;border-top: 1px solid black;border-right: 1px solid black;border-bottom: 1px solid black;border-left: 1px solid black;;">2701201201</td><td style="font-weight: bold;text-align: center;border-left: 1px solid black;;">1</td></tr><tr><td style="color: #161120;text-align: center;">29</td><td style="font-weight: bold;text-align: center;border-top: 1px solid black;border-right: 1px solid black;border-bottom: 1px solid black;border-left: 1px solid black;;">27/01/12</td><td style="font-weight: bold;text-align: center;border-top: 1px solid black;border-right: 1px solid black;border-bottom: 1px solid black;border-left: 1px solid black;;">CP</td><td style="font-weight: bold;text-align: center;border-top: 1px solid black;border-right: 1px solid black;border-bottom: 1px solid black;border-left: 1px solid black;;">
</td><td style="font-weight: bold;text-align: center;border-top: 1px solid black;border-right: 1px solid black;border-bottom: 1px solid black;border-left: 1px solid black;;">y</td><td style="font-weight: bold;text-align: center;border-top: 1px solid black;border-right: 1px solid black;border-bottom: 1px solid black;border-left: 1px solid black;;">2701201202</td><td style="font-weight: bold;text-align: center;border-left: 1px solid black;;">1</td></tr></tbody></table>
Receipting


<table rules="all" style=";border: 2px solid black;border-collapse:collapse;padding: 0.4em;background-color: #FFFFFF" cellpadding="2.5px" width="85%"><tbody><tr><td style="padding:6px">Worksheet Formulas<table rules="all" style="border: 1px solid;text-align:center;background-color: #FFFFFF;border-collapse: collapse; border-color: #A6AAB6" cellpadding="2.5px" width="100%"><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 style=" background-color: #E0E0F0;color: #161120" width="10px">J27</th><td style="text-align:left">=IF(OR(H27="y",I27="y"),TEXT(A27,"ddmmyyyy")&TEXT(SUMPRODUCT(($A$3:A27=A27)*($O$3:O27=1)),"00"),"")</td></tr><tr><th style=" background-color: #E0E0F0;color: #161120" width="10px">J28</th><td style="text-align:left">=IF(OR(H28="y",I28="y"),TEXT(A28,"ddmmyyyy")&TEXT(SUMPRODUCT(($A$3:A28=A28)*($O$3:O28=1)),"00"),"")</td></tr><tr><th style=" background-color: #E0E0F0;color: #161120" width="10px">J29</th><td style="text-align:left">=IF(OR(H29="y",I29="y"),TEXT(A29,"ddmmyyyy")&TEXT(SUMPRODUCT(($A$3:A29=A29)*($O$3:O29=1)),"00"),"")</td></tr><tr><th style=" background-color: #E0E0F0;color: #161120" width="10px">O27</th><td style="text-align:left">=IF(OR(H27="Y",I27="Y"),1,"")</td></tr><tr><th style=" background-color: #E0E0F0;color: #161120" width="10px">O28</th><td style="text-align:left">=IF(OR(H28="Y",I28="Y"),1,"")</td></tr><tr><th style=" background-color: #E0E0F0;color: #161120" width="10px">O29</th><td style="text-align:left">=IF(OR(H29="Y",I29="Y"),1,"")</td></tr></tbody></table></td></tr></tbody></table>
 
Thanks for the quick response but this formula "=IF(OR(H27="y",I27="y"),TEXT(A27,"ddmmyyyy")&TEXT(SUMPRODUCT(--($A$3:A27=A27)),"00"),"") " will not do what I need the formula to do.

The formula I need is this -
1. check if H OR I cols have a "Y"
2. If Yes then text(datecol,"ddmmyyyy") AND count the number of rows where H OR I cols have a "Y" and the date matches the date of the current row

see the count of rows (SampleID col) where H OR I cols have a "Y" Matrix below
Note that the 1st date entry has no samples, therefore no count & no sample ID.

Next 3 dates of the same date have a "either, or" or both sample types & therefore are counted in the count of sample ID from current row & all matching dates above the current entry. This works with the helper cell.

Excel 2003<table rules="all" style=";background-color: #FFFFFF;border: 1px solid;border-collapse: collapse; border-color: #A6AAB6" cellpadding="2.5px"><colgroup><col style="background-color: #E0E0F0" width="25px"><col><col><col><col><col></colgroup><thead><tr style=" background-color: #E0E0F0;text-align: center;color: #161120"><th>
</th><th>A</th><th>H</th><th>I</th><th>J</th><th>O</th></tr></thead><tbody><tr><td style="color: #161120;text-align: center;">2</td><td style="font-weight: bold;text-align: center;border-top: 1px solid black;border-right: 1px solid black;border-bottom: 1px solid black;border-left: 1px solid black;;">Date</td><td style="font-weight: bold;text-align: center;border-top: 1px solid black;border-right: 1px solid black;border-bottom: 1px solid black;border-left: 1px solid black;;">Liquid Sample taken</td><td style="font-weight: bold;text-align: center;border-top: 1px solid black;border-right: 1px solid black;border-bottom: 1px solid black;border-left: 1px solid black;;">Solid Sample taken</td><td style="font-weight: bold;text-align: center;border-top: 1px solid black;border-right: 1px solid black;border-bottom: 1px solid black;border-left: 1px solid black;;">Sample ID</td><td style="font-weight: bold;text-align: center;;">
</td></tr><tr><td style="color: #161120;text-align: center;">20</td><td style="font-weight: bold;text-align: center;border-top: 1px solid black;border-right: 1px solid black;border-bottom: 1px solid black;border-left: 1px solid black;;">24/01/12</td><td style="font-weight: bold;text-align: center;border-top: 1px solid black;border-right: 1px solid black;border-bottom: 1px solid black;border-left: 1px solid black;;">
</td><td style="font-weight: bold;text-align: center;border-top: 1px solid black;border-right: 1px solid black;border-bottom: 1px solid black;border-left: 1px solid black;;">
</td><td style="font-weight: bold;text-align: center;border-top: 1px solid black;border-right: 1px solid black;border-bottom: 1px solid black;border-left: 1px solid black;;">
</td><td style="font-weight: bold;text-align: center;border-left: 1px solid black;;">
</td></tr><tr><td style="color: #161120;text-align: center;">21</td><td style="font-weight: bold;text-align: center;border-top: 1px solid black;border-right: 1px solid black;border-bottom: 1px solid black;border-left: 1px solid black;;">24/01/12</td><td style="font-weight: bold;text-align: center;border-top: 1px solid black;border-right: 1px solid black;border-bottom: 1px solid black;border-left: 1px solid black;;">
</td><td style="font-weight: bold;text-align: center;border-top: 1px solid black;border-right: 1px solid black;border-bottom: 1px solid black;border-left: 1px solid black;;">y</td><td style="font-weight: bold;text-align: center;border-top: 1px solid black;border-right: 1px solid black;border-bottom: 1px solid black;border-left: 1px solid black;;">2401201201</td><td style="font-weight: bold;text-align: center;border-left: 1px solid black;;">1</td></tr><tr><td style="color: #161120;text-align: center;">22</td><td style="font-weight: bold;text-align: center;border-top: 1px solid black;border-right: 1px solid black;border-bottom: 1px solid black;border-left: 1px solid black;;">24/01/12</td><td style="font-weight: bold;text-align: center;border-top: 1px solid black;border-right: 1px solid black;border-bottom: 1px solid black;border-left: 1px solid black;;">y</td><td style="font-weight: bold;text-align: center;border-top: 1px solid black;border-right: 1px solid black;border-bottom: 1px solid black;border-left: 1px solid black;;">
</td><td style="font-weight: bold;text-align: center;border-top: 1px solid black;border-right: 1px solid black;border-bottom: 1px solid black;border-left: 1px solid black;;">2401201202</td><td style="font-weight: bold;text-align: center;border-left: 1px solid black;;">1</td></tr><tr><td style="color: #161120;text-align: center;">23</td><td style="font-weight: bold;text-align: center;border-top: 1px solid black;border-right: 1px solid black;border-bottom: 1px solid black;border-left: 1px solid black;;">24/01/12</td><td style="font-weight: bold;text-align: center;border-top: 1px solid black;border-right: 1px solid black;border-bottom: 1px solid black;border-left: 1px solid black;;">y</td><td style="font-weight: bold;text-align: center;border-top: 1px solid black;border-right: 1px solid black;border-bottom: 1px solid black;border-left: 1px solid black;;">y</td><td style="font-weight: bold;text-align: center;border-top: 1px solid black;border-right: 1px solid black;border-bottom: 1px solid black;border-left: 1px solid black;;">2401201203</td><td style="font-weight: bold;text-align: center;border-left: 1px solid black;;">1</td></tr></tbody></table>
Receipting (2)


<table rules="all" style=";border: 2px solid black;border-collapse:collapse;padding: 0.4em;background-color: #FFFFFF" cellpadding="2.5px" width="85%"><tbody><tr><td style="padding:6px">Worksheet Formulas<table rules="all" style="border: 1px solid;text-align:center;background-color: #FFFFFF;border-collapse: collapse; border-color: #A6AAB6" cellpadding="2.5px" width="100%"><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 style=" background-color: #E0E0F0;color: #161120" width="10px">J20</th><td style="text-align:left">=IF(OR(H20="y",I20="y"),TEXT(A20,"ddmmyyyy")&TEXT(SUMPRODUCT(($A$3:A20=A20)*($O$3:O20=1)),"00"),"")</td></tr><tr><th style=" background-color: #E0E0F0;color: #161120" width="10px">J21</th><td style="text-align:left">=IF(OR(H21="y",I21="y"),TEXT(A21,"ddmmyyyy")&TEXT(SUMPRODUCT(($A$3:A21=A21)*($O$3:O21=1)),"00"),"")</td></tr><tr><th style=" background-color: #E0E0F0;color: #161120" width="10px">J22</th><td style="text-align:left">=IF(OR(H22="y",I22="y"),TEXT(A22,"ddmmyyyy")&TEXT(SUMPRODUCT(($A$3:A22=A22)*($O$3:O22=1)),"00"),"")</td></tr><tr><th style=" background-color: #E0E0F0;color: #161120" width="10px">J23</th><td style="text-align:left">=IF(OR(H23="y",I23="y"),TEXT(A23,"ddmmyyyy")&TEXT(SUMPRODUCT(($A$3:A23=A23)*($O$3:O23=1)),"00"),"")</td></tr><tr><th style=" background-color: #E0E0F0;color: #161120" width="10px">O20</th><td style="text-align:left">=IF(OR(H20="Y",I20="Y"),1,"")</td></tr><tr><th style=" background-color: #E0E0F0;color: #161120" width="10px">O21</th><td style="text-align:left">=IF(OR(H21="Y",I21="Y"),1,"")</td></tr><tr><th style=" background-color: #E0E0F0;color: #161120" width="10px">O22</th><td style="text-align:left">=IF(OR(H22="Y",I22="Y"),1,"")</td></tr><tr><th style=" background-color: #E0E0F0;color: #161120" width="10px">O23</th><td style="text-align:left">=IF(OR(H23="Y",I23="Y"),1,"")</td></tr></tbody></table></td></tr></tbody></table>


The helper cell works but it would be nice to do away with it.
 
Upvote 0
Maybe this

J20
=IF(OR(H20="Y",I20="Y"),TEXT(A20,"ddmmmyyyy")&TEXT(SUMPRODUCT(--($A$3:A20=A20),--((($H$3:H20="Y")+($I$3:I20="Y"))>0)),"00"),"")

M.
 
Upvote 0

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