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


How to return non-grouped items from a GROUP BY statement?


How to return non-grouped items from a GROUP BY statement?

Author
Message
ANSA_Naz
ANSA_Naz
SSC-Enthusiastic
SSC-Enthusiastic (145 reputation)SSC-Enthusiastic (145 reputation)SSC-Enthusiastic (145 reputation)SSC-Enthusiastic (145 reputation)SSC-Enthusiastic (145 reputation)SSC-Enthusiastic (145 reputation)SSC-Enthusiastic (145 reputation)SSC-Enthusiastic (145 reputation)

Group: General Forum Members
Points: 145 Visits: 90

Hi all

I have the following data in table MyTrans:

Account Date Amount RecID
100000 15/02/2018 100.00 1
100000 25/02/2018 150.00 2
100000 25/02/2018 50.00 3
100002 15/02/2018 200.00 4
100002 15/02/2018 1500.00 5
100002 15/02/2018 -250.00 6
100002 25/02/2018 145.00 7
100002 25/02/2018 -145.00 8
100002 01/03/2018 -25.00 9
100003 01/03/2018 1950.00 10

See below SQL to create this table:

create table #MyTrans
(
Account nvarchar(6),
Date datetime,
Amount numeric(18,2),
RecID varchar(2)
)

INSERT INTO #MyTrans(Account, Date, Amount, RecID) values
('100000','15/02/2018','100.00','1'),
('100000','25/02/2018','150.00','2'),
('100000','25/02/2018','50.00','3'),
('100002','15/02/2018','200.00','4'),
('100002','15/02/2018','1500.00','5'),
('100002','15/02/2018','-250.00','6'),
('100002','25/02/2018','145.00','7'),
('100002','25/02/2018','-145.00','8'),
('100002','01/03/2018','-25.00','9'),
('100003','01/03/2018','1950.00','10')

I want to return only those records where the total per Account and then per Date, is greater than 0, eg for the above dataset I want to return:

Account Date Amount RecID
100000 15/02/2018 100.00 1
100000 25/02/2018 150.00 2
100000 25/02/2018 50.00 3
100002 15/02/2018 200.00 4
100002 15/02/2018 1500.00 5
100002 15/02/2018 -250.00 6
100003 01/03/2018 1950.00 10


My query is currently as follows:

Select Account, Date, sum(Amount) as Amount, RecID
From #MyTrans
group by Account, Date
Having sum(Amount)>0

However, I cannot do it this way as the RecID column is not in the Group By statement, even though I dont want to grouo by this column. I am unsure how I can return the RecID and have the group by statement not group on this column. Does anyone have any ideas?

Cheers for all help


John Mitchell-245523
John Mitchell-245523
SSC Guru
SSC Guru (130K reputation)SSC Guru (130K reputation)SSC Guru (130K reputation)SSC Guru (130K reputation)SSC Guru (130K reputation)SSC Guru (130K reputation)SSC Guru (130K reputation)SSC Guru (130K reputation)

Group: General Forum Members
Points: 130783 Visits: 19092
WITH Grouped AS (
SELECT
Account
, Date
, SUM(Amount) OVER (PARTITION BY Account, Date) AS Amount
, RecID
FROM #MyTrans
)
SELECT
Account
, Date
, Amount
, RecID
FROM Grouped
WHERE Amount > 0


John

ANSA_Naz
ANSA_Naz
SSC-Enthusiastic
SSC-Enthusiastic (145 reputation)SSC-Enthusiastic (145 reputation)SSC-Enthusiastic (145 reputation)SSC-Enthusiastic (145 reputation)SSC-Enthusiastic (145 reputation)SSC-Enthusiastic (145 reputation)SSC-Enthusiastic (145 reputation)SSC-Enthusiastic (145 reputation)

Group: General Forum Members
Points: 145 Visits: 90
Thanks John, thats brill!
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