ExcelBanter

ExcelBanter (https://www.excelbanter.com/)
-   Excel Discussion (Misc queries) (https://www.excelbanter.com/excel-discussion-misc-queries/)
-   -   Count if using multiple date criteria (https://www.excelbanter.com/excel-discussion-misc-queries/248571-count-if-using-multiple-date-criteria.html)

GPearson

Count if using multiple date criteria
 
Hello:

I am working on a spreadsheet that records inventory. I need to create a
formula that counts if any items were completed late by a person . The
information regarding the person is recorded in one of two columns (M and N).
The date completed is recorded in column O. The due date is column G. I
also need to record this for each month received. The received date is
column A. So for example, I need to know how many items received in November
2009 and assigned to J. Smith were completed after the due date.

Thanks for any help you can give!


JBeaucaire[_131_]

Count if using multiple date criteria
 
Something like this:

=SUMPRODUCT(--(DATE(YEAR($A$2:$A$21),
MONTH($A$2:$A$21), 1) = DATE(2009, 11, 1)), --($M$2:$M$21="Jerry"),
--($G$2:$G$21<$O$2:$O$21))

Or:

=SUMPRODUCT(--(DATE(YEAR($A$2:$A$21),
MONTH($A$2:$A$21), 1) = DATE(2009, 11, 1)),
($M$2:$M$21="Jerry")+($N$2:$N$21="Jerry"), --($G$2:$G$21<$O$2:$O$21))

Does that help?

--
"Actually, I *am* a rocket scientist." -- JB
(www.MadRocketScientist.com)

Your feedback is appreciated, click YES if this post helped you.


"GPearson" wrote:

Hello:

I am working on a spreadsheet that records inventory. I need to create a
formula that counts if any items were completed late by a person . The
information regarding the person is recorded in one of two columns (M and N).
The date completed is recorded in column O. The due date is column G. I
also need to record this for each month received. The received date is
column A. So for example, I need to know how many items received in November
2009 and assigned to J. Smith were completed after the due date.

Thanks for any help you can give!


GPearson

Count if using multiple date criteria
 
Thanks for your help. I actually had a seperate spreadsheet that had only
one assignment column and the first formula worked great for that. However,
I tried to use the 2nd formula on the spreadsheet that had 2 assignment
columns. Unfortuntely, it only counted the occurances where the assignment
was in the first column (M). It did not count the occurances where the
assignment was in the 2nd column (N). Can you assist with this?

Thanks!

"JBeaucaire" wrote:

Something like this:

=SUMPRODUCT(--(DATE(YEAR($A$2:$A$21),
MONTH($A$2:$A$21), 1) = DATE(2009, 11, 1)), --($M$2:$M$21="Jerry"),
--($G$2:$G$21<$O$2:$O$21))

Or:

=SUMPRODUCT(--(DATE(YEAR($A$2:$A$21),
MONTH($A$2:$A$21), 1) = DATE(2009, 11, 1)),
($M$2:$M$21="Jerry")+($N$2:$N$21="Jerry"), --($G$2:$G$21<$O$2:$O$21))

Does that help?

--
"Actually, I *am* a rocket scientist." -- JB
(www.MadRocketScientist.com)

Your feedback is appreciated, click YES if this post helped you.


"GPearson" wrote:

Hello:

I am working on a spreadsheet that records inventory. I need to create a
formula that counts if any items were completed late by a person . The
information regarding the person is recorded in one of two columns (M and N).
The date completed is recorded in column O. The due date is column G. I
also need to record this for each month received. The received date is
column A. So for example, I need to know how many items received in November
2009 and assigned to J. Smith were completed after the due date.

Thanks for any help you can give!


JBeaucaire[_131_]

Count if using multiple date criteria
 
No, it works in my testing. Something we can't see must be interfering.

Shorten the range down to 10 rows or so, then use the Formula Auditing
toolbar's "Evaluate Formula" icon to step through the formula on calc at a
time, see if you can spot the calc that is not working.

You can send me your sheet to troubleshoot.

Jerry
AT
devstudios
DOT
com

--
"Actually, I *am* a rocket scientist." -- JB
(www.MadRocketScientist.com)

Your feedback is appreciated, click YES if this post helped you.


"GPearson" wrote:

Thanks for your help. I actually had a seperate spreadsheet that had only
one assignment column and the first formula worked great for that. However,
I tried to use the 2nd formula on the spreadsheet that had 2 assignment
columns. Unfortuntely, it only counted the occurances where the assignment
was in the first column (M). It did not count the occurances where the
assignment was in the 2nd column (N). Can you assist with this?

Thanks!

"JBeaucaire" wrote:

Something like this:

=SUMPRODUCT(--(DATE(YEAR($A$2:$A$21),
MONTH($A$2:$A$21), 1) = DATE(2009, 11, 1)), --($M$2:$M$21="Jerry"),
--($G$2:$G$21<$O$2:$O$21))

Or:

=SUMPRODUCT(--(DATE(YEAR($A$2:$A$21),
MONTH($A$2:$A$21), 1) = DATE(2009, 11, 1)),
($M$2:$M$21="Jerry")+($N$2:$N$21="Jerry"), --($G$2:$G$21<$O$2:$O$21))

Does that help?

--
"Actually, I *am* a rocket scientist." -- JB
(www.MadRocketScientist.com)

Your feedback is appreciated, click YES if this post helped you.


"GPearson" wrote:

Hello:

I am working on a spreadsheet that records inventory. I need to create a
formula that counts if any items were completed late by a person . The
information regarding the person is recorded in one of two columns (M and N).
The date completed is recorded in column O. The due date is column G. I
also need to record this for each month received. The received date is
column A. So for example, I need to know how many items received in November
2009 and assigned to J. Smith were completed after the due date.

Thanks for any help you can give!


GPearson

Count if using multiple date criteria
 
This worked great! I was able to find the problem.
Thanks again!

"JBeaucaire" wrote:

No, it works in my testing. Something we can't see must be interfering.

Shorten the range down to 10 rows or so, then use the Formula Auditing
toolbar's "Evaluate Formula" icon to step through the formula on calc at a
time, see if you can spot the calc that is not working.

You can send me your sheet to troubleshoot.

Jerry
AT
devstudios
DOT
com

--
"Actually, I *am* a rocket scientist." -- JB
(www.MadRocketScientist.com)

Your feedback is appreciated, click YES if this post helped you.


"GPearson" wrote:

Thanks for your help. I actually had a seperate spreadsheet that had only
one assignment column and the first formula worked great for that. However,
I tried to use the 2nd formula on the spreadsheet that had 2 assignment
columns. Unfortuntely, it only counted the occurances where the assignment
was in the first column (M). It did not count the occurances where the
assignment was in the 2nd column (N). Can you assist with this?

Thanks!

"JBeaucaire" wrote:

Something like this:

=SUMPRODUCT(--(DATE(YEAR($A$2:$A$21),
MONTH($A$2:$A$21), 1) = DATE(2009, 11, 1)), --($M$2:$M$21="Jerry"),
--($G$2:$G$21<$O$2:$O$21))

Or:

=SUMPRODUCT(--(DATE(YEAR($A$2:$A$21),
MONTH($A$2:$A$21), 1) = DATE(2009, 11, 1)),
($M$2:$M$21="Jerry")+($N$2:$N$21="Jerry"), --($G$2:$G$21<$O$2:$O$21))

Does that help?

--
"Actually, I *am* a rocket scientist." -- JB
(www.MadRocketScientist.com)

Your feedback is appreciated, click YES if this post helped you.


"GPearson" wrote:

Hello:

I am working on a spreadsheet that records inventory. I need to create a
formula that counts if any items were completed late by a person . The
information regarding the person is recorded in one of two columns (M and N).
The date completed is recorded in column O. The due date is column G. I
also need to record this for each month received. The received date is
column A. So for example, I need to know how many items received in November
2009 and assigned to J. Smith were completed after the due date.

Thanks for any help you can give!



All times are GMT +1. The time now is 11:43 PM.

Powered by vBulletin® Copyright ©2000 - 2024, Jelsoft Enterprises Ltd.
ExcelBanter.com