Sumproduct no worky!

ChrisM

Well-known Member
Joined
Jun 11, 2002
Messages
2,129
Can anyone see why this formula won't work?

=SUMPRODUCT((WEEKNUM(DataClerkDay)=WEEKNUM(E67))*(DataClerkCustShip))

It's a modification of this formula, which DOES work:

=SUMPRODUCT((MONTH(DataClerkDay)=MONTH($E$1))*(DataClerkDistShip))

The named range "DataClerkDay" refers to a column of 32 days, like:
12/1
12/2
12/3
etc

Range "DataClerkDistShip" is a column of numbers

Cells E67 and E1 in their respective formulas
refer to date criteria like "12/1/02" or 12/15/02".

Any help is appreciated, I'm sort of new to sumproduct formulas.

Thanks!

((EDIT: cell is reporting a #value error. a value in formula is wrong data type))
This message was edited by ChrisM on 2002-12-31 09:10
 

Excel Facts

Why does 9 mean SUM in SUBTOTAL?
It is because Sum is the 9th alphabetically in Average, Count, CountA, Max, Min, Product, StDev.S, StDev.P, Sum, VAR.S, VAR.P.
They both work for me when the same data is entered in the cells referred to...must be something in those cells on your sheet.
 
Upvote 0
The date criteria cells are date formatted like "12/1/2002", the date range cells are date/time formatted like "12/1/2002 12:00". The dataclerkcustship range is left as general format.
 
Upvote 0
On 2002-12-31 10:11, ChrisM wrote:
The date criteria cells are date formatted like "12/1/2002", the date range cells are date/time formatted like "12/1/2002 12:00". The dataclerkcustship range is left as general format.
Is the formula gacking on the cell w/ the time appended to it, or the one w/ date only? Also, though I don't think this is your problem since you're at least getting a val error msg, but...: If this function is not available, run the Setup program to install the Analysis ToolPak. After you install the Analysis ToolPak, you must enable it by using the Add-Ins command on the Tools menu.
 
Upvote 0
On 2002-12-31 09:01, ChrisM wrote:
Can anyone see why this formula won't work?

=SUMPRODUCT((WEEKNUM(DataClerkDay)=WEEKNUM(E67))*(DataClerkCustShip))

It's a modification of this formula, which DOES work:

=SUMPRODUCT((MONTH(DataClerkDay)=MONTH($E$1))*(DataClerkDistShip))

The named range "DataClerkDay" refers to a column of 32 days, like:
12/1
12/2
12/3
etc

Range "DataClerkDistShip" is a column of numbers

Cells E67 and E1 in their respective formulas
refer to date criteria like "12/1/02" or 12/15/02".

Any help is appreciated, I'm sort of new to sumproduct formulas.

Thanks!

((EDIT: cell is reporting a #value error. a value in formula is wrong data type))
This message was edited by ChrisM on 2002-12-31 09:10

WEEKNUM applied to a multicell range will error out (results in #VALUE). That is, this function cannot return an array constant that the SumProduct formula needs.

Apply to each cell of DataClerkDay the following formula...

=WEEKNUM(X)

where X is the first cell of DataClerkDay.

Use the new range, named as say WeekNums, in the original formula...

=SUMPRODUCT((WeekNums=WEEKNUM(E67))*(DataClerkCustShip))

Aladin
 
Upvote 0

Forum statistics

Threads
1,215,454
Messages
6,124,933
Members
449,195
Latest member
Stevenciu

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