Click here to monitor SSC
SQLServerCentral is supported by Red Gate Software Ltd.
 
Log in  ::  Register  ::  Not logged in
 
 
 
        
Home       Members    Calendar    Who's On


Add to briefcase

Max with distinct two columns and corresponding third column Expand / Collapse
Author
Message
Posted Wednesday, April 30, 2014 12:13 PM
Forum Newbie

Forum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum Newbie

Group: General Forum Members
Last Login: Wednesday, April 30, 2014 2:21 PM
Points: 1, Visits: 8
Hi, i need to write a query and can't get it to work no matter how it try. Here's what i need:

T1
-------
a1
a2
datetime
a4
a5
.....

i need distinct max between a1&a2 which i can get no problem but i cant get that unique datetime that correspond to a1&a2 in 1 query because this is will a subquery in a big query. Creating another temp table etc is not an option for me. Is there any way to do it?
PS.
for every specific a1 there is many entries of a2 + timedate etc.


create table abc_test (
id int
,runs int
,date1 datetime
)

insert into abc_test (
id
,runs
,date1
) values
('24','1','2013-12-05 10:00:01.000'),
('24','2','2013-12-05 10:00:02.000'),
('25','1','2013-12-05 10:00:03.000'),
('25','2','2013-12-05 10:00:04.000'),
('25','3','2013-12-05 10:00:06.000'),
('26','1','2013-12-05 10:00:07.000'),
('26','2','2013-12-05 10:00:08.000'),
('21','1','2013-12-05 10:00:09.000')




id runs date1
----------- ----------- -----------------------
24 1 2013-12-05 10:00:01.000
24 2 2013-12-05 10:00:02.000
25 1 2013-12-05 10:00:03.000
25 2 2013-12-05 10:00:04.000
25 3 2013-12-05 10:00:06.000
26 1 2013-12-05 10:00:07.000
26 2 2013-12-05 10:00:08.000
27 1 2013-12-05 10:00:09.000

(8 row(s) affected)


Expected Result

id          runs        date1
----------- ----------- -----------------------
24 2 2013-12-05 10:00:02.000
25 3 2013-12-05 10:00:06.000
26 2 2013-12-05 10:00:08.000
27 1 2013-12-05 10:00:09.000



I can either get distinct ID + latest date or ID + largest #ofRuns, both will do but also need the third column.

Thanks in advance
Post #1566540
Posted Wednesday, April 30, 2014 12:27 PM


SSChampion

SSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampion

Group: General Forum Members
Last Login: Today @ 3:05 PM
Points: 13,320, Visits: 12,804
Hi and welcome to the forums. In order to help we will need a few things:

1. Sample DDL in the form of CREATE TABLE statements
2. Sample data in the form of INSERT INTO statements
3. Expected results based on the sample data

Please take a few minutes and read the first article in my signature for best practices when posting questions.


_______________________________________________________________

Need help? Help us help you.

Read the article at http://www.sqlservercentral.com/articles/Best+Practices/61537/ for best practices on asking questions.

Need to split a string? Try Jeff Moden's splitter.

Cross Tabs and Pivots, Part 1 – Converting Rows to Columns
Cross Tabs and Pivots, Part 2 - Dynamic Cross Tabs
Understanding and Using APPLY (Part 1)
Understanding and Using APPLY (Part 2)
Post #1566549
Posted Thursday, May 1, 2014 2:32 AM
SSC Veteran

SSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC Veteran

Group: General Forum Members
Last Login: Sunday, September 14, 2014 12:30 AM
Points: 253, Visits: 540
May be this will help you
declare  @abc_test as table (
id int ,runs int ,date1 datetime
)
insert into @abc_test ( id ,runs ,date1 )
values
('24','1','2013-12-05 10:00:01.000'),
('24','2','2013-12-05 10:00:02.000'),
('25','1','2013-12-05 10:00:03.000'),
('25','2','2013-12-05 10:00:04.000'),
('25','3','2013-12-05 10:00:06.000'),
('26','1','2013-12-05 10:00:07.000'),
('26','2','2013-12-05 10:00:08.000'),
('21','1','2013-12-05 10:00:09.000');

WITH cte AS (
SELECT ROW_NUMBER() OVER(PARTITION BY id ORDER BY Runs DESC) rn,*
FROM @abc_test
)
SELECT * FROM CTE
WHERE RN =1





Every rule in a world of bits and bytes, can be bend or eventually be broken
MyBlog About Common dialog control
A Visualizer for viewing SqlCommand object script
Post #1566652
Posted Tuesday, May 6, 2014 12:59 PM
SSC Eights!

SSC Eights!SSC Eights!SSC Eights!SSC Eights!SSC Eights!SSC Eights!SSC Eights!SSC Eights!

Group: General Forum Members
Last Login: Monday, November 3, 2014 11:20 AM
Points: 825, Visits: 725
Here is another option.

create table abc_test 
(
id int
,runs int
,date1 datetime
)
;

insert into abc_test
(
id
,runs
,date1
) values
('24','1','2013-12-05 10:00:01.000'),
('24','2','2013-12-05 10:00:02.000'),
('25','1','2013-12-05 10:00:03.000'),
('25','2','2013-12-05 10:00:04.000'),
('25','3','2013-12-05 10:00:06.000'),
('26','1','2013-12-05 10:00:07.000'),
('26','2','2013-12-05 10:00:08.000'),
('27','1','2013-12-05 10:00:09.000')
;

SELECT T2.id
, [runs] = T2.MaxRuns
, T1.date1
FROM dbo.abc_test T1
INNER JOIN
(
SELECT id
, [MaxRuns] = MAX(runs)
FROM dbo.abc_test
GROUP BY id
) T2
ON T1.id = T2.id AND T1.runs = T2.MaxRuns
ORDER BY T2.id
;


Regards,

Brian
Post #1568145
Posted Tuesday, May 6, 2014 1:24 PM


SSChampion

SSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampion

Group: General Forum Members
Last Login: Today @ 3:05 PM
Points: 13,320, Visits: 12,804
bkmsmith (5/6/2014)
Here is another option.

create table abc_test 
(
id int
,runs int
,date1 datetime
)
;

insert into abc_test
(
id
,runs
,date1
) values
('24','1','2013-12-05 10:00:01.000'),
('24','2','2013-12-05 10:00:02.000'),
('25','1','2013-12-05 10:00:03.000'),
('25','2','2013-12-05 10:00:04.000'),
('25','3','2013-12-05 10:00:06.000'),
('26','1','2013-12-05 10:00:07.000'),
('26','2','2013-12-05 10:00:08.000'),
('27','1','2013-12-05 10:00:09.000')
;

SELECT T2.id
, [runs] = T2.MaxRuns
, T1.date1
FROM dbo.abc_test T1
INNER JOIN
(
SELECT id
, [MaxRuns] = MAX(runs)
FROM dbo.abc_test
GROUP BY id
) T2
ON T1.id = T2.id AND T1.runs = T2.MaxRuns
ORDER BY T2.id
;


Regards,

Brian


That should return the correct data but you are hitting the table twice instead of once. Performance wise this is going to be slower.


_______________________________________________________________

Need help? Help us help you.

Read the article at http://www.sqlservercentral.com/articles/Best+Practices/61537/ for best practices on asking questions.

Need to split a string? Try Jeff Moden's splitter.

Cross Tabs and Pivots, Part 1 – Converting Rows to Columns
Cross Tabs and Pivots, Part 2 - Dynamic Cross Tabs
Understanding and Using APPLY (Part 1)
Understanding and Using APPLY (Part 2)
Post #1568157
Posted Tuesday, May 6, 2014 1:34 PM
SSC Eights!

SSC Eights!SSC Eights!SSC Eights!SSC Eights!SSC Eights!SSC Eights!SSC Eights!SSC Eights!

Group: General Forum Members
Last Login: Monday, November 3, 2014 11:20 AM
Points: 825, Visits: 725
Sean Lange (5/6/2014)
bkmsmith (5/6/2014)
Here is another option.

create table abc_test 
(
id int
,runs int
,date1 datetime
)
;

insert into abc_test
(
id
,runs
,date1
) values
('24','1','2013-12-05 10:00:01.000'),
('24','2','2013-12-05 10:00:02.000'),
('25','1','2013-12-05 10:00:03.000'),
('25','2','2013-12-05 10:00:04.000'),
('25','3','2013-12-05 10:00:06.000'),
('26','1','2013-12-05 10:00:07.000'),
('26','2','2013-12-05 10:00:08.000'),
('27','1','2013-12-05 10:00:09.000')
;

SELECT T2.id
, [runs] = T2.MaxRuns
, T1.date1
FROM dbo.abc_test T1
INNER JOIN
(
SELECT id
, [MaxRuns] = MAX(runs)
FROM dbo.abc_test
GROUP BY id
) T2
ON T1.id = T2.id AND T1.runs = T2.MaxRuns
ORDER BY T2.id
;


Regards,

Brian


That should return the correct data but you are hitting the table twice instead of once. Performance wise this is going to be slower.


True. Point taken.

Regards,

Brian
Post #1568161
« Prev Topic | Next Topic »

Add to briefcase

Permissions Expand / Collapse