DSUM an alternative for SUMPRODUCT

mucah!t

Well-known Member
Joined
Jun 27, 2009
Messages
593
Hello all

I'using a lot of Sumproduct formulas on my sheet, which slows down the file considerably. I did some searching on the internet and DSUM seems to be a good alternative for Sumproduct. However, its hard to find a good example.
Perhaps one of you know how it can be applied.

This is the formula I'm using at this moment

Code:
=SUMPRODUCT(--('R-overzicht'!$L$5:$L$2000=$C4);--(MONTH('R-overzicht'!$M$5:$M$2000)=MONTH(D$2))*(YEAR('R-overzicht'!$M$5:$M$2000)=YEAR(D$2));'R-overzicht'!$J$5:$J$2000)
 

Some videos you may like

Excel Facts

What did Pito Salas invent?
Pito Salas, working for Lotus, popularized what would become to be pivot tables. It was released as Lotus Improv in 1989.

mikerickson

MrExcel MVP
Joined
Jan 15, 2007
Messages
23,770
DSUM, etc. are a good substitute for SUMPRODUCT, but....

The criteria range has to be a range, it won't accept explicit arrays.

The common useage of putting a SUMPRODUCT formula on a row and dragging down to return the value for the next row will not work with a DSUM formula. Dragging down will either loose the header row of the Criteria Range or expand the Criteria Range, creating an OR.

To return values for a single, user defined scenario, DSUM is fine. Or Perhaps a bit better. (The criteria range is a pretty self explainaitory user interface.)

As a formula as a part of a table of data, SUMPRODUCT is much better.
 

mucah!t

Well-known Member
Joined
Jun 27, 2009
Messages
593
I hoped that Dsum would solve all my problems... :(
Can any of you think of an alternative?

This is the File I'm working on, not all data is shown though
 

mikerickson

MrExcel MVP
Joined
Jan 15, 2007
Messages
23,770
Its not clear what your problem is. In the OP you say that you are using SUMPRODUCT, but you don't mention what problems this causes.

It looks like that formula is doing something similar to a SUMIFS.
 

mucah!t

Well-known Member
Joined
Jun 27, 2009
Messages
593

ADVERTISEMENT

Like I said, it slows down the file considerably because of the calculations.
In the example file only a couple of them are shown but the file I'm working on has a lot of them [sumproduct-formulas]
 

Aladin Akyurek

MrExcel MVP
Joined
Feb 14, 2002
Messages
85,192

ADVERTISEMENT

I hoped that Dsum would solve all my problems... :(
Can any of you think of an alternative?

This is the File I'm working on, not all data is shown though
By the way, you invoke an unnecessarily high-cost formula...

D4, just enter, copy across and down:

=SUMPRODUCT(--('1'!$D$5:$D$1081=$C4),--('1'!$E$5:$E$1081-DAY('1'!$E$5:$E$1081)+1=D$2),'1'!$B$5:$B$1081)

Recall that comma must be semi-colon on your system.
 

AlphaFrog

MrExcel MVP
Joined
Sep 2, 2009
Messages
16,271
If you're willing to use a helper column on sheet 1, you could replace your SUMPRODUCT formulas with SIMIF formulas. SUMIF should be faster.
Excel Workbook
ABCDEF
4DATUMBEDRAGOMSCHRIJVINGPOSTMNDHelper
523/07/2010 12.00GFStest1Jul072010test1
623/07/2010 234.00KUYRJtest1Jul072010test1
723/07/2010 5.00REWtest2Jul072010test2
823/07/2010 76.00YTREUYTtest3Jul072010test3
923/07/2010 54.00EUTtest1Jul072010test1
1023/07/2010 44.00REYTtest2Jul072010test2
1123/07/2010 56.00RWYtest2Jul072010test2
1223/07/2010 65.00T4WYUUTtest3Jul072010test3
1
Excel 2002
Cell Formulas
RangeFormula
F5=TEXT(A5,"mmyyyy")&D5
F6=TEXT(A6,"mmyyyy")&D6
F7=TEXT(A7,"mmyyyy")&D7
F8=TEXT(A8,"mmyyyy")&D8
F9=TEXT(A9,"mmyyyy")&D9
F10=TEXT(A10,"mmyyyy")&D10
F11=TEXT(A11,"mmyyyy")&D11
F12=TEXT(A12,"mmyyyy")&D12
Excel Workbook
ACDEFGHIJ
1
2InkomstenJanFebMarAprMayJunJul
3
4test1 - - - - - - 300.00
5test2 - - - - - - 105.00
6test3 - - - - - - 141.00
2
Excel 2002
Cell Formulas
RangeFormula
D4=SUMIF('1'!$F:$F,TEXT(D$2,"mmyyyy")&$C4,'1'!$B:$B)
D5=SUMIF('1'!$F:$F,TEXT(D$2,"mmyyyy")&$C5,'1'!$B:$B)
D6=SUMIF('1'!$F:$F,TEXT(D$2,"mmyyyy")&$C6,'1'!$B:$B)
E4=SUMIF('1'!$F:$F,TEXT(E$2,"mmyyyy")&$C4,'1'!$B:$B)
E5=SUMIF('1'!$F:$F,TEXT(E$2,"mmyyyy")&$C5,'1'!$B:$B)
E6=SUMIF('1'!$F:$F,TEXT(E$2,"mmyyyy")&$C6,'1'!$B:$B)
F4=SUMIF('1'!$F:$F,TEXT(F$2,"mmyyyy")&$C4,'1'!$B:$B)
F5=SUMIF('1'!$F:$F,TEXT(F$2,"mmyyyy")&$C5,'1'!$B:$B)
F6=SUMIF('1'!$F:$F,TEXT(F$2,"mmyyyy")&$C6,'1'!$B:$B)
G4=SUMIF('1'!$F:$F,TEXT(G$2,"mmyyyy")&$C4,'1'!$B:$B)
G5=SUMIF('1'!$F:$F,TEXT(G$2,"mmyyyy")&$C5,'1'!$B:$B)
G6=SUMIF('1'!$F:$F,TEXT(G$2,"mmyyyy")&$C6,'1'!$B:$B)
H4=SUMIF('1'!$F:$F,TEXT(H$2,"mmyyyy")&$C4,'1'!$B:$B)
H5=SUMIF('1'!$F:$F,TEXT(H$2,"mmyyyy")&$C5,'1'!$B:$B)
H6=SUMIF('1'!$F:$F,TEXT(H$2,"mmyyyy")&$C6,'1'!$B:$B)
I4=SUMIF('1'!$F:$F,TEXT(I$2,"mmyyyy")&$C4,'1'!$B:$B)
I5=SUMIF('1'!$F:$F,TEXT(I$2,"mmyyyy")&$C5,'1'!$B:$B)
I6=SUMIF('1'!$F:$F,TEXT(I$2,"mmyyyy")&$C6,'1'!$B:$B)
J4=SUMIF('1'!$F:$F,TEXT(J$2,"mmyyyy")&$C4,'1'!$B:$B)
J5=SUMIF('1'!$F:$F,TEXT(J$2,"mmyyyy")&$C5,'1'!$B:$B)
J6=SUMIF('1'!$F:$F,TEXT(J$2,"mmyyyy")&$C6,'1'!$B:$B)
 

AlphaFrog

MrExcel MVP
Joined
Sep 2, 2009
Messages
16,271
You could also do this with a Pivot Table. You would still need to make helper columns on sheet 1
Excel Workbook
ABCDEFGH
4DATUMBEDRAGOMSCHRIJVINGPOSTMNDMonthYearMo & Yr
523/07/2010 12.00GFStest1JulJul2010Jul 2010
623/07/2010 234.00KUYRJtest1JulJul2010Jul 2010
723/07/2010 5.00REWtest2JulJul2010Jul 2010
823/07/2010 76.00YTREUYTtest3JulJul2010Jul 2010
923/07/2010 54.00EUTtest1JulJul2010Jul 2010
1023/07/2010 44.00REYTtest2JulJul2010Jul 2010
1123/07/2010 56.00RWYtest2JulJul2010Jul 2010
1223/07/2010 65.00T4WYUUTtest3JulJul2010Jul 2010
1
Excel 2002
Cell Formulas
RangeFormula
F5=TEXT(A5,"mmm")
G5=YEAR(A5)
H5=TEXT(A5,"mmm yyyy")


Then set up your pivot table so that...
Page Area
Month
Year

Row area
Post

Column area
Month & Year

Data area
Sum of BEDRAG
 

Subscribe on YouTube

Watch MrExcel Video

Forum statistics

Threads
1,106,616
Messages
5,512,428
Members
408,894
Latest member
Sara Russell

This Week's Hot Topics

  • Sort code advice please
    Hi, I have the code below which im trying to edit but getting a little stuck. This was the original code which worked fine,columns A-F would sort...
  • SUMPRODUCT with nested If statement
    Hi everyone, Hope you're all well. I'm hoping someone will be able to point me in the right direction with a problem I'm having with a SUMPRODUCT...
  • VBA - simple sort is killing me!
    Hello all! This should be so easy, but not for me, apparently! I have a table of data that can be of varying lengths and widths. My current macro...
  • Compare Two Lists
    I have two Lists and I need to be able to Identify differences between them. List 100 comes from a workbook - the other is downloaded form the...
  • Formula that deducts points for each code I input.
    I am trying to create a formula that will have each student in my class start at 100 points and then for each code that I enter (PP for Poor...
  • Conditional formatting formula required for day of week and a value
    Hi, I have a really simple spreadsheet where column A is the date, column B is the activity total shown as a number and column C states the day of...
Top