DSUM criteria problem

mgirvin

Well-known Member
Joined
Dec 15, 2005
Messages
1,236
Office Version
  1. 365
Platform
  1. Windows
Dear Amazing World MrExcel Team,

I have a DSUM formula that seems to work with the field item "NorthEast", but it seems to add incorrectly when I use "North".


Here is the situation that adds correctly:

=DSUM(A1:E5000,”Sales”,G8:K9)

Where G8:K9 looks like this:

Region SalesRep Customer
NorthEast Luke The Economist


Here is the situation that adds incorrectly

=DSUM(A1:E5000,”Sales”,G8:K9)

Where G8:K9 looks like this:

Region SalesRep Customer
North Luke The Economist


Any ideas about what is going on?
 

Excel Facts

Wildcard in VLOOKUP
Use =VLOOKUP("Apple*" to find apple, Apple, or applesauce
Dear Aladin,

This is the second time you have given me great Excel help, Aladin! Thank you for the ="=North" trick!

But why? Do you know how this helps DSUM work?

In addition, I had an array formula and a Boolean formula that were using the same criteria (North), but now that the DSUM formula works, the array and Boolean formulas do not work.

Is the ="=North" trick a well know trick that many people use with DSUM or other Database functions?
 
Upvote 0
Dear Aladin,

This is the second time you have given me great Excel help, Aladin! Thank you for the ="=North" trick!

You are welcome.

But why? Do you know how this helps DSUM work?

D-functions evaluate text-criteria like Advanced Filter does, all this I suppose by desgn:

North alone means "Starts with" and ="=North" means "Equal to".

In addition, I had an array formula and a Boolean formula that were using the same criteria (North), but now that the DSUM formula works, the array and Boolean formulas do not work.

Yep. You might want to try one of the options that follow:
aaDSumCritProblem mgirvin.xls
ABCDEFGHIJ
1Northa"
2XWYXWdsumSum+IfSum+If
3Northa5=North=a555
4NorthEasta7
5
6
Sheet1


F1 and G1 houses actual text criteria.

F2:G2 houses formulas to prepare criteria such that DSUM can take them as "Equal To"...

F2, copied across to G2:

="="&F1

H3:

=DSUM($A$2:$C$4,"Y",$F$2:$G$3)

I3:

{=SUM(IF($A$3:$A$4=F1,IF($B$3:$B$4=G1,$C$3:$C$4)))}

refers to the criteria in F1:G1.

J3:

{=SUM(IF($A$3:$A$4=SUBSTITUTE(F3,"=",""),IF($B$3:$B$4=SUBSTITUTE(G1,"=",""),$C$3:$C$4)))}

refers to F2:G2 as DSUM does, evidently incurring a small cost.

Is the ="=North" trick a well know trick that many people use with DSUM or other Database functions?

Yes, they have to.
 
Upvote 0

Forum statistics

Threads
1,214,967
Messages
6,122,503
Members
449,090
Latest member
RandomExceller01

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