Please start any new threads on our new site at https://forums.sqlteam.com. We've got lots of great SQL Server experts to answer whatever question you can come up with.

 All Forums
 General SQL Server Forums
 New to SQL Server Programming
 Nested Agregate

Author  Topic 

martinorth
Starting Member

3 Posts

Posted - 2013-06-25 : 06:05:21
Please, can anyone tell me why the date range of the first query works and but at the second query the date range inside the count() does not have an effect on the result? (MS SQL Server 2005)

SELECT COUNT(B.STATK_AUFNR) AS besuche

FROM

(SELECT

A.STATK_AUFNR,
A.STATK_BEZIRK,
A.STATK_KDNR,
A.STATK_BES_ART,
A.STATK_AUF_DATUM,
A.STATK_AUF_WERT AS brutto,
Sum(B.STATP_FAKT_SUMME) AS netto

FROM

GKKopf A

INNER JOIN GKPos B ON A.STATK_AUFNR = B.STATP_AUFNR AND A.STATK_BEZIRK = B.STATP_BEZIRK

WHERE A.statk_auf_datum >= {d '2013-01-01'}
AND A.statk_auf_datum <= {d '2013-03-31'} ) B

second query

SELECT

COUNT(CASE WHEN A.statk_auf_datum >= {d '2013-01-01'} AND A.statk_auf_datum <= {d '2013-03-31'} THEN B.STATK_AUFNR ELSE 0 END) AS besuche

FROM

(SELECT

A.STATK_AUFNR,
A.STATK_BEZIRK,
A.STATK_KDNR,
A.STATK_BES_ART,
A.STATK_AUF_DATUM,
A.STATK_AUF_WERT AS brutto,
Sum(B.STATP_FAKT_SUMME) AS netto

FROM

GKKopf A

INNER JOIN GKPos B ON A.STATK_AUFNR = B.STATP_AUFNR AND A.STATK_BEZIRK = B.STATP_BEZIRK) B

bandi
Master Smack Fu Yak Hacker

2242 Posts

Posted - 2013-06-25 : 06:09:51
COUNT(CASE WHEN A.statk_auf_datum >= {d '2013-01-01'} AND A.statk_auf_datum <= {d '2013-03-31'} THEN B.STATK_AUFNR ELSE 0 END) AS besuche
-- There are syntactical errors also
SELECT COUNT(CASE WHEN B.statk_auf_datum >= {d '2013-01-01'} AND B.statk_auf_datum <= {d '2013-03-31'} THEN B.STATK_AUFNR ELSE 0 END) AS besuche
FROM (SELECT
A.STATK_AUFNR,
A.STATK_BEZIRK,
A.STATK_KDNR,
A.STATK_BES_ART,
A.STATK_AUF_DATUM,
A.STATK_AUF_WERT AS brutto,
Sum(B.STATP_FAKT_SUMME) AS netto ---- either you have to put non-aggregate column in GROUP BY Clause or use OVER() Clause to avoid syntax error
FROM GKKopf A
INNER JOIN
GKPos B ON A.STATK_AUFNR = B.STATP_AUFNR AND A.STATK_BEZIRK = B.STATP_BEZIRK) B

--
Chandu
Go to Top of Page

visakh16
Very Important crosS Applying yaK Herder

52326 Posts

Posted - 2013-06-25 : 06:12:34
the first one does a filter on whole query based on date range whereas second one does it inside the count. so there are equivalent. But reason why you didnt get correct result in second case is because of a typo

it should be


SELECT

COUNT(CASE WHEN A.statk_auf_datum >= {d '2013-01-01'} AND A.statk_auf_datum <= {d '2013-03-31'} THEN B.STATK_AUFNR ELSE 0NULL END) AS besuche

FROM

(SELECT

A.STATK_AUFNR,
A.STATK_BEZIRK,
A.STATK_KDNR,
A.STATK_BES_ART,
A.STATK_AUF_DATUM,
A.STATK_AUF_WERT AS brutto,
Sum(B.STATP_FAKT_SUMME) AS netto

FROM

GKKopf A

INNER JOIN GKPos B ON A.STATK_AUFNR = B.STATP_AUFNR AND A.STATK_BEZIRK = B.STATP_BEZIRK) B

As 0 will still mean it will include it as valid record. if you want to use 0 for exclusion you should be applying SUM rather than COUNT

ie


SELECT

SUM(CASE WHEN A.statk_auf_datum >= {d '2013-01-01'} AND A.statk_auf_datum <= {d '2013-03-31'} THEN 1 ELSE 0 END) AS besuche

FROM

(SELECT

A.STATK_AUFNR,
A.STATK_BEZIRK,
A.STATK_KDNR,
A.STATK_BES_ART,
A.STATK_AUF_DATUM,
A.STATK_AUF_WERT AS brutto,
Sum(B.STATP_FAKT_SUMME) AS netto

FROM

GKKopf A

INNER JOIN GKPos B ON A.STATK_AUFNR = B.STATP_AUFNR AND A.STATK_BEZIRK = B.STATP_BEZIRK) B


------------------------------------------------------------------------------------------------------
SQL Server MVP
http://visakhm.blogspot.com/
https://www.facebook.com/VmBlogs
Go to Top of Page
   

- Advertisement -