Sumprodct count dates

Paddy1979

Well-known Member
Joined
Sep 23, 2005
Messages
608
Hi All, please can you help.

I have this formular to count the dates in sheet 'jobs' column 'I' that are in the past, but its not counting the figures correctly.

Is there somthing i am missing?

=SUMPRODUCT(--(JOBS!$N$1:$N$4594=Sheet1!$B2),--(JOBS!$I$1:$I$4594 < TODAY()))

Thanks
Paddy
 

Excel Facts

Format cells as date
Select range and press Ctrl+Shift+3 to format cells as date. (Shift 3 is the # sign which sort of looks like a small calendar).
What is the first condition of your formula checking?

Can you tell us what is in columns N, I and in cell Sheet1!$B2?
 
Upvote 0
Hello,

the first condition is customer id codes, so colmn N and b2 contain numbers. column I contains dates
 
Upvote 0
Are the dates in column I in date format, or text format?
 
Upvote 0
The dates are in date format,

I cant lock $B$2 as its part of a macro which loops down.

I have other sumproduct formulas working of B2 and they are working perfectly its just this one with the dates, strange
 
Upvote 0
Are your IDs in the same format? Are you sure neither one has an extra space anywhere?

If not, can you post a small sample of your data?
 
Upvote 0
One quick check to make sure your logic is working out, and to identify where the problem exists.

Identify a row that should be counted. For this example, let's say row 4. Try each part of your formula:

Does this return TRUE?
=JOBS!$N$4=Sheet1!$B2

How about this?
=JOBS!$I$4 < TODAY()

If either one returns FALSE, that is the source of your problem. The values that you think are equal really aren't (probably didn't formats, or extra spaces).
 
Upvote 0
Jim,

JACKPOT

Just spotted column I with the dates does contain some blank cells.

Obviouly this must be the reason, how can i adjust my forular to not count the blank cells???

Cheers
 
Upvote 0
Add another condition to make sure a date exists, i.e.

=SUMPRODUCT(--(JOBS!$N$1:$N$4594=Sheet1!$B2),--(JOBS!$I$1:$I$4594 < TODAY()),--(JOBS!$I$1:$I$4594 > 0))
 
Upvote 0

Forum statistics

Threads
1,213,490
Messages
6,113,956
Members
448,535
Latest member
alrossman

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