SQL Clone
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


Help with aggregate function


Help with aggregate function

Author
Message
ger_serrano
ger_serrano
SSC Veteran
SSC Veteran (222 reputation)SSC Veteran (222 reputation)SSC Veteran (222 reputation)SSC Veteran (222 reputation)SSC Veteran (222 reputation)SSC Veteran (222 reputation)SSC Veteran (222 reputation)SSC Veteran (222 reputation)

Group: General Forum Members
Points: 222 Visits: 23
have table:
col1 col2 col3
A B 10
B A 5
C D 8

Want to get:
A B 15
C D 8
ZZartin
ZZartin
SSC-Insane
SSC-Insane (23K reputation)SSC-Insane (23K reputation)SSC-Insane (23K reputation)SSC-Insane (23K reputation)SSC-Insane (23K reputation)SSC-Insane (23K reputation)SSC-Insane (23K reputation)SSC-Insane (23K reputation)

Group: General Forum Members
Points: 23252 Visits: 16171
And how are you determining that

A B 10
B A 5

Should aggregate to A B 15
ger_serrano
ger_serrano
SSC Veteran
SSC Veteran (222 reputation)SSC Veteran (222 reputation)SSC Veteran (222 reputation)SSC Veteran (222 reputation)SSC Veteran (222 reputation)SSC Veteran (222 reputation)SSC Veteran (222 reputation)SSC Veteran (222 reputation)

Group: General Forum Members
Points: 222 Visits: 23
col1 and col2 represent company names and col3 is the transaction value, could be negative, between the companies. So I want to know how much company A spent?
Luis Cazares
Luis Cazares
SSC Guru
SSC Guru (152K reputation)SSC Guru (152K reputation)SSC Guru (152K reputation)SSC Guru (152K reputation)SSC Guru (152K reputation)SSC Guru (152K reputation)SSC Guru (152K reputation)SSC Guru (152K reputation)

Group: General Forum Members
Points: 152560 Visits: 22275
Lengthy, but there might not be a better alternative without fixing the data.

CREATE TABLE SampleData(
col1 varchar(10),
col2 varchar(10),
col3 int
);
INSERT INTO SampleData
VALUES
('A', 'B', 10),
('B', 'A', 5 ),
('C', 'D', 8 );


SELECT CASE WHEN col1 <= col2 THEN col1 ELSE col2 END AS col1,
CASE WHEN col1 <= col2 THEN col2 ELSE col1 END AS col2,
SUM( col3) AS col3
FROM SampleData
GROUP BY CASE WHEN col1 <= col2 THEN col1 ELSE col2 END,
CASE WHEN col1 <= col2 THEN col2 ELSE col1 END;

GO
DROP TABLE SampleData



Luis C.
General Disclaimer:
Are you seriously taking the advice and code from someone from the internet without testing it? Do you at least understand it? Or can it easily kill your server?


How to post data/code on a forum to get the best help: Option 1 / Option 2
Jeff Moden
Jeff Moden
SSC Guru
SSC Guru (816K reputation)SSC Guru (816K reputation)SSC Guru (816K reputation)SSC Guru (816K reputation)SSC Guru (816K reputation)SSC Guru (816K reputation)SSC Guru (816K reputation)SSC Guru (816K reputation)

Group: General Forum Members
Points: 816302 Visits: 46260

It won't make a bit of improvement performance-wise over what Luis posted, but it does simplify the code a bit. The derived table could be a CTE or CROSS APPLY, as well. Since this is also for 2012 or greater, we can use IIF for further code simplification although they do resolve to CASE operators behind the scenes.


SELECT d.Col1, d.Col2, Col3 = SUM(d.COL3)
FROM (
SELECT Col1 = IIF(Col1<=Col2, Col1, Col2)
,Col2 = IIF(Col1<=Col2, Col2, Col1)
,Col3
FROM dbo.SampleData
) d
GROUP BY d.Col1, d.Col2
;


Also, I recommend that you always use the 2 part naming convention for all tables and objects in all of your code.



--Jeff Moden

RBAR is pronounced ree-bar and is a Modenism for Row-By-Agonizing-Row.
First step towards the paradigm shift of writing Set Based code:
Stop thinking about what you want to do to a row... think, instead, of what you want to do to a column.
If you think its expensive to hire a professional to do the job, wait until you hire an amateur. -- Red Adair

Helpful Links:
How to post code problems
How to post performance problems
Forum FAQs
ger_serrano
ger_serrano
SSC Veteran
SSC Veteran (222 reputation)SSC Veteran (222 reputation)SSC Veteran (222 reputation)SSC Veteran (222 reputation)SSC Veteran (222 reputation)SSC Veteran (222 reputation)SSC Veteran (222 reputation)SSC Veteran (222 reputation)

Group: General Forum Members
Points: 222 Visits: 23
That is excellent guys. Both queries work as expected. I have modified the query a little bit to accomodate a case when col3 is negative. In that case it means that for company col1 is a loss but for comany col2 is a plus.so for examble for the following values;
col1 col2 col3
A B 100
B A -50
A C 200
A D 100
A B 150
B F 200
The result of the modified queries:
SELECT CASE WHEN col1 <= col2 THEN col1 ELSE col2 END AS col1,
CASE WHEN col1 <= col2 THEN col2 ELSE col1 END AS col2,
SUM( CASE WHEN col3 < 0 THEN col3 * -1 ELSE col3 END ) AS col3
FROM SampleData
GROUP BY CASE WHEN col1 <= col2 THEN col1 ELSE col2 END,
CASE WHEN col1 <= col2 THEN col2 ELSE col1 END;

SELECT d.col1, d.col2, col3 = SUM(IIF (d.col3 < 0, d.col3 * -1, d.col3))
FROM (
SELECT col1 = IIF(col1<=col2, col1, col2)
,col2 = IIF(col1<=col2, col2, col1)
,col3
FROM SampleData
) d
GROUP BY d.col1, d.col2
;
Result:
A B 300
A C 200
A D 100
B F 200

That is what I wanted!!
I got all the help I requested. Thank you very much. From my prespective we can close this thread, Not sure who is going to do it.
Jeff Moden
Jeff Moden
SSC Guru
SSC Guru (816K reputation)SSC Guru (816K reputation)SSC Guru (816K reputation)SSC Guru (816K reputation)SSC Guru (816K reputation)SSC Guru (816K reputation)SSC Guru (816K reputation)SSC Guru (816K reputation)

Group: General Forum Members
Points: 816302 Visits: 46260
ger_serrano - Monday, November 20, 2017 9:11 AM
That is excellent guys. Both queries work as expected. I have modified the query a little bit to accomodate a case when col3 is negative. In that case it means that for company col1 is a loss but for comany col2 is a plus.so for examble for the following values;
col1 col2 col3
A B 100
B A -50
A C 200
A D 100
A B 150
B F 200
The result of the modified queries:
SELECT CASE WHEN col1 <= col2 THEN col1 ELSE col2 END AS col1,
CASE WHEN col1 <= col2 THEN col2 ELSE col1 END AS col2,
SUM( CASE WHEN col3 < 0 THEN col3 * -1 ELSE col3 END ) AS col3
FROM SampleData
GROUP BY CASE WHEN col1 <= col2 THEN col1 ELSE col2 END,
CASE WHEN col1 <= col2 THEN col2 ELSE col1 END;

SELECT d.col1, d.col2, col3 = SUM(IIF (d.col3 < 0, d.col3 * -1, d.col3))
FROM (
SELECT col1 = IIF(col1<=col2, col1, col2)
,col2 = IIF(col1<=col2, col2, col1)
,col3
FROM SampleData
) d
GROUP BY d.col1, d.col2
;
Result:
A B 300
A C 200
A D 100
B F 200

That is what I wanted!!
I got all the help I requested. Thank you very much. From my prespective we can close this thread, Not sure who is going to do it.


Thanks for the kind feedback and about your modification. Threads are never closed, though, just in case someone comes up with a better idea that will help us all for similar problems.

--Jeff Moden

RBAR is pronounced ree-bar and is a Modenism for Row-By-Agonizing-Row.
First step towards the paradigm shift of writing Set Based code:
Stop thinking about what you want to do to a row... think, instead, of what you want to do to a column.
If you think its expensive to hire a professional to do the job, wait until you hire an amateur. -- Red Adair

Helpful Links:
How to post code problems
How to post performance problems
Forum FAQs
ger_serrano
ger_serrano
SSC Veteran
SSC Veteran (222 reputation)SSC Veteran (222 reputation)SSC Veteran (222 reputation)SSC Veteran (222 reputation)SSC Veteran (222 reputation)SSC Veteran (222 reputation)SSC Veteran (222 reputation)SSC Veteran (222 reputation)

Group: General Forum Members
Points: 222 Visits: 23
Sorry . that was only half of the work I had to do. tuens out that every time I have negative value in col3 I have to turn col3 positive and flip col1 and col2 values and then group so if have:
col1 col2 col3
A B 100
B A -50
A C 200
A D 100
A B 150
B F 200
C D -50
I have to produce
col1 col2 col3
A B 300
A C 200
A D 100
B F 200
D C 50
ger_serrano
ger_serrano
SSC Veteran
SSC Veteran (222 reputation)SSC Veteran (222 reputation)SSC Veteran (222 reputation)SSC Veteran (222 reputation)SSC Veteran (222 reputation)SSC Veteran (222 reputation)SSC Veteran (222 reputation)SSC Veteran (222 reputation)

Group: General Forum Members
Points: 222 Visits: 23
Following query produced the expected results:
A B 300
A C 200
A D 100
B F 200
D C 50

SELECT CASE WHEN COL1 <= COL2 AND COL3 > 0 THEN COL1 ELSE COL2 END AS COL1,
CASE WHEN COL1 <= COL2 AND COL3 > 0 THEN COL2 ELSE COL1 END AS COL2,
SUM( CASE WHEN COL3 < 0 THEN COL3 *-1 ELSE COL3 END ) AS COL3
FROM SampleData
GROUP BY CASE WHEN COL1 <= COL2 AND COL3 > 0 THEN COL1 ELSE COL2 END,
CASE WHEN COL1 <= COL2 AND COL3 > 0 THEN COL2 ELSE COL1 END
ORDER BY CASE WHEN COL1 <= COL2 AND COL3 > 0 THEN COL1 ELSE COL2 END,
CASE WHEN COL1 <= COL2 AND COL3 > 0 THEN COL2 ELSE COL1 END
ger_serrano
ger_serrano
SSC Veteran
SSC Veteran (222 reputation)SSC Veteran (222 reputation)SSC Veteran (222 reputation)SSC Veteran (222 reputation)SSC Veteran (222 reputation)SSC Veteran (222 reputation)SSC Veteran (222 reputation)SSC Veteran (222 reputation)

Group: General Forum Members
Points: 222 Visits: 23
unfortunately taht query did not encompass all scenarios such as:
col1 col2 col3
('A','B',100),
('B','A',-50),
('A','C',200),
('A','D',100),
('A','B',150),
('B','F',200),
('d','K',400),
('K','D',-20),
('C','D',-50),
('D','C',-60);
I need to display which one of col1 or col2 had the max net value (col3). I mean I have to have as a result:
A,B,300
A,C,200
A,D,100
B,F,200
D,K,420
C,D,10
hopefully this table will help to cover all 4 scenarios of values between col1 and col2 (first two rows). Last four rows is the answer we need to get:
A B 30 30 -30 -30
B A 90 -90 90 -90
B A 60
A B 120
B A 120
A B 60
sԾ��9w
Go


Permissions

You can't post new topics.
You can't post topic replies.
You can't post new polls.
You can't post replies to polls.
You can't edit your own topics.
You can't delete your own topics.
You can't edit other topics.
You can't delete other topics.
You can't edit your own posts.
You can't edit other posts.
You can't delete your own posts.
You can't delete other posts.
You can't post events.
You can't edit your own events.
You can't edit other events.
You can't delete your own events.
You can't delete other events.
You can't send private messages.
You can't send emails.
You can read topics.
You can't vote in polls.
You can't upload attachments.
You can download attachments.
You can't post HTML code.
You can't edit HTML code.
You can't post IFCode.
You can't post JavaScript.
You can post emoticons.
You can't post or upload images.

Select a forum








































































































































































SQLServerCentral


Search