sumproduct help

Muthukrishnan V

Active Member
Joined
May 29, 2008
Messages
269
Office Version
  1. 365
Platform
  1. Windows
Excel 2007



Formula in S3:
=SUMPRODUCT(--
(D3:D20,D23:D47,D51:D67,D70:D74,D77:D124,D129:D140,D143:
D153,D156:D157=R3),P3:P20,P23:P47,P51:P67,P70:P74,P77:P12
4,P129:P140,P143:P153,P156:P157)

Column D contains Amount in numericals.

Column R3 is a Helper Cell containing name like KM in general

format.

Column P contains names like KM and so on.


With the above formula in S3, I get : #Value !.

Kindly help.
 

Excel Facts

What is the fastest way to copy a formula?
If A2:A50000 contain data. Enter a formula in B2. Select B2. Double-click the Fill Handle and Excel will shoot the formula down to B50000.
It will not work with ranges broken up like that, see if this works

=SUMPRODUCT(D3:D157,--(P3:P157=R3))
 
Upvote 0
Your set-up is unclear to me as your attempted formula seems to indicate names in column D but your written description says they are in column P. I have assumed column P is the correct one for names with numbers in D.
Try this

=SUMPRODUCT(--(P3:P157=R3),LOOKUP(ROW(P3:P157),{3,21,23,48,51,68,70,75,77,125,129,141,143,154,156},{1,0,1,0,1,0,1,0,1,0,1,0,1,0,1}),D3:D157)


Edit:
.. or a little shorter :)

=SUMPRODUCT(--(P3:P157=R3),--ISODD(MATCH(ROW(P3:P157),{3,21,23,48,51,68,70,75,77,125,129,141,143,154,156})),D3:D157)

=SUMPRODUCT(--(P3:P157=R3),--MOD(MATCH(ROW(P3:P157),{3,21,23,48,51,68,70,75,77,125,129,141,143,154,156}),2),D3:D157)
 
Last edited:
Upvote 0

Forum statistics

Threads
1,213,543
Messages
6,114,238
Members
448,555
Latest member
RobertJones1986

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