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
 SQL Server 2008 Forums
 Transact-SQL (2008)
 select query two sum fields based on diff conditio

Author  Topic 

cplusplus
Aged Yak Warrior

567 Posts

Posted - 2013-07-23 : 13:47:58
Is it possible to have two diff conditions for sum fields, I want to sum(RMQTY01) as IP,sum(RMQTY01) as OP FROM BPBSRMP

based on RMyear, RMDEPT, RMITEM.

this condition is specific to IP sum calc: AND RMPTYP <> 'I'

this condition is specific to OP sum calc: AND RMPTYP = 'I'

SELECT rmyear, rmdept,rmitem, sum(RMQTY01) as IP,sum(RMQTY01) as OP FROM BPBSRMP
WHERE RMHSP = 1
AND RMYEAR = 12
AND RMDEPT <> 0
AND RMRCTP in('D', 'T', 'O', '4')
AND RMUSE in('C', 'R');

Thank you very much for the helpful info.

James K
Master Smack Fu Yak Hacker

3873 Posts

Posted - 2013-07-23 : 13:54:42
quote:
Originally posted by cplusplus

I want to sum(RMQTY01) as IP,sum(RMQTY01) as OP FROM BPBSRMP

based on RMyear, RMDEPT, RMITEM.

this condition is specific to IP sum calc: AND RMPTYP <> 'I'

this condition is specific to OP sum calc: AND RMPTYP <> 'I'

SELECT rmyear, rmdept,rmitem, sum(RMQTY01) as IP,sum(RMQTY01) as OP FROM BPBSRMP
WHERE RMHSP = 1
AND RMYEAR = 12
AND RMDEPT <> 0
AND RMRCTP in('D', 'T', 'O', '4')
AND RMUSE in('C', 'R');

Thank you very much for the helpful info.

Since the condition is the same for both types of sums, and the quantity being summed is the same, wouldn't both sums produce the same result?

Regardless, what you want to do is use a case expression within the aggregate like shown below:
SELECT  rmyear ,
rmdept ,
rmitem ,
SUM(CASE WHEN RMPTYP <> 'I' THEN RMQTY01 ELSE 0 END) AS IP ,
SUM(CASE WHEN RMPTYP <> 'I' THEN RMQTY01 ELSE 0 END) AS OP
FROM BPBSRMP
WHERE RMHSP = 1
AND RMYEAR = 12
AND RMDEPT <> 0
AND RMRCTP IN ( 'D', 'T', 'O', '4' )
AND RMUSE IN ( 'C', 'R' );
Go to Top of Page

cplusplus
Aged Yak Warrior

567 Posts

Posted - 2013-07-23 : 14:12:02
Sorry James,

I didn't realize, that is a mistake by me. the condition is different, one <> & other =
Go to Top of Page

James K
Master Smack Fu Yak Hacker

3873 Posts

Posted - 2013-07-23 : 14:29:31
I suspected something like that, but didn't want to assume that on your behalf ;)
Just change the <> to = in one of the case expressions.

If you can have NULL in the RMPTYP column, the corresponding RMQTY01 values will not get aggregated into either sum. If that is a concern, you should change the test to COALESCE(RMTYP,'X') <> 'I' (or the other way around depending on which bucket you want the rows that have RMTYP=NULL to fall into.
Go to Top of Page

visakh16
Very Important crosS Applying yaK Herder

52326 Posts

Posted - 2013-07-24 : 02:00:20
quote:
Originally posted by James K

quote:
Originally posted by cplusplus

I want to sum(RMQTY01) as IP,sum(RMQTY01) as OP FROM BPBSRMP

based on RMyear, RMDEPT, RMITEM.

this condition is specific to IP sum calc: AND RMPTYP <> 'I'

this condition is specific to OP sum calc: AND RMPTYP <> 'I'

SELECT rmyear, rmdept,rmitem, sum(RMQTY01) as IP,sum(RMQTY01) as OP FROM BPBSRMP
WHERE RMHSP = 1
AND RMYEAR = 12
AND RMDEPT <> 0
AND RMRCTP in('D', 'T', 'O', '4')
AND RMUSE in('C', 'R');

Thank you very much for the helpful info.

Since the condition is the same for both types of sums, and the quantity being summed is the same, wouldn't both sums produce the same result?

Regardless, what you want to do is use a case expression within the aggregate like shown below:
SELECT  rmyear ,
rmdept ,
rmitem ,
SUM(CASE WHEN RMPTYP <> 'I' THEN RMQTY01 ELSE 0 END) AS IP ,
SUM(CASE WHEN RMPTYP <> 'I' THEN RMQTY01 ELSE 0 END) AS OP
FROM BPBSRMP
WHERE RMHSP = 1
AND RMYEAR = 12
AND RMDEPT <> 0
AND RMRCTP IN ( 'D', 'T', 'O', '4' )
AND RMUSE IN ( 'C', 'R' );
GROUP BY rmyear ,
rmdept ,
rmitem




it needs a GROUP BY

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

- Advertisement -