April 30, 2014 at 12:13 pm
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
April 30, 2014 at 12:27 pm
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 Modens splitter http://www.sqlservercentral.com/articles/Tally+Table/72993/.
Cross Tabs and Pivots, Part 1 – Converting Rows to Columns - http://www.sqlservercentral.com/articles/T-SQL/63681/
Cross Tabs and Pivots, Part 2 - Dynamic Cross Tabs - http://www.sqlservercentral.com/articles/Crosstab/65048/
Understanding and Using APPLY (Part 1) - http://www.sqlservercentral.com/articles/APPLY/69953/
Understanding and Using APPLY (Part 2) - http://www.sqlservercentral.com/articles/APPLY/69954/
May 1, 2014 at 2:32 am
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 [/url]
May 6, 2014 at 12:59 pm
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')
;
SELECTT2.id
, [runs] = T2.MaxRuns
, T1.date1
FROMdbo.abc_test T1
INNER JOIN
(
SELECTid
, [MaxRuns] = MAX(runs)
FROMdbo.abc_test
GROUP BY id
) T2
ON T1.id = T2.id AND T1.runs = T2.MaxRuns
ORDER BY T2.id
;
Regards,
Brian
May 6, 2014 at 1:24 pm
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')
;
SELECTT2.id
, [runs] = T2.MaxRuns
, T1.date1
FROMdbo.abc_test T1
INNER JOIN
(
SELECTid
, [MaxRuns] = MAX(runs)
FROMdbo.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 Modens splitter http://www.sqlservercentral.com/articles/Tally+Table/72993/.
Cross Tabs and Pivots, Part 1 – Converting Rows to Columns - http://www.sqlservercentral.com/articles/T-SQL/63681/
Cross Tabs and Pivots, Part 2 - Dynamic Cross Tabs - http://www.sqlservercentral.com/articles/Crosstab/65048/
Understanding and Using APPLY (Part 1) - http://www.sqlservercentral.com/articles/APPLY/69953/
Understanding and Using APPLY (Part 2) - http://www.sqlservercentral.com/articles/APPLY/69954/
May 6, 2014 at 1:34 pm
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')
;
SELECTT2.id
, [runs] = T2.MaxRuns
, T1.date1
FROMdbo.abc_test T1
INNER JOIN
(
SELECTid
, [MaxRuns] = MAX(runs)
FROMdbo.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
Viewing 6 posts - 1 through 5 (of 5 total)
You must be logged in to reply to this topic. Login to reply