January 7, 2011 at 1:16 pm
Hi,
I've tried to solve this but cannot come up with the proper SQL. Given these records I need to group them so that the most recent record appears 1st, followed by all that person's records (time descending). Then find the next person with a max time less than the max time of the 1st group and list all of their records (time descending), and so on.
Here are the records -
Mr. ADAMS2011-01-07 17:00:00
Mr. BEACH2011-01-07 16:30:00
Mr. BEACH2011-01-07 16:00:00
Mr. SCHAL2011-01-07 15:30:00
Mr. ADAMS2011-01-07 15:00:00
Mr. SCHAL2011-01-07 14:30:00
Mr. JONES2011-01-07 14:00:00
Mr. BEACH2011-01-07 13:00:00
And this is what I'm trying achieve -
Mr. ADAMS2011-01-07 17:00:00
Mr. ADAMS2011-01-07 15:00:00
Mr. BEACH2011-01-07 16:30:00
Mr. BEACH2011-01-07 16:00:00
Mr. BEACH2011-01-07 13:00:00
Mr. SCHAL2011-01-07 15:30:00
Mr. SCHAL2011-01-07 14:30:00
Mr. JONES2011-01-07 14:00:00
D
January 7, 2011 at 1:47 pm
First thing that comes to mind is substring. You can group by substring(column,1,10) and order by substring(column,11,19) desc
January 7, 2011 at 1:57 pm
create table #test(person varchar(50),dated smalldatetime);
insert #test
values('Mr. ADAMS ','2011-01-07 17:00:00')
,('Mr. BEACH ','2011-01-07 16:30:00')
,('Mr. BEACH ','2011-01-07 16:00:00')
,('Mr. SCHAL ','2011-01-07 15:30:00')
,('Mr. ADAMS ','2011-01-07 15:00:00')
,('Mr. SCHAL ','2011-01-07 14:30:00')
,('Mr. JONES ','2011-01-07 14:00:00')
,('Mr. BEACH ','2011-01-07 13:00:00')
select t1.person,t1.dated
from #test t1
join (
select person,max(dated) as maxdate
from #test
group by person
) t2
on t2.person=t1.person
order by t2.maxdate desc,dated desc
MM
select geometry::STGeomFromWKB(0x0106000000020000000103000000010000000B0000001000000000000840000000000000003DD8CCCCCCCCCC0840000000000000003DD8CCCCCCCCCC08408014AE47E17AFC3F040000000000104000CDCCCCCCCCEC3F9C999999999913408014AE47E17AFC3F9C99999999991340000000000000003D0000000000001440000000000000003D000000000000144000000000000000400400000000001040000000000000F03F100000000000084000000000000000401000000000000840000000000000003D0103000000010000000B000000000000000000143D000000000000003D009E99999999B93F000000000000003D009E99999999B93F8014AE47E17AFC3F400000000000F03F00CDCCCCCCCCEC3FA06666666666FE3F8014AE47E17AFC3FA06666666666FE3F000000000000003D1800000000000040000000000000003D18000000000000400000000000000040400000000000F03F000000000000F03F000000000000143D0000000000000040000000000000143D000000000000003D, 0);
January 7, 2011 at 2:06 pm
Does this work for you?
create table #Temp (A varchar(255), B Datetime)
insert into #Temp
values('Mr. ADAMS', '2011-01-07 17:00:00'),
('Mr. BEACH', '2011-01-07 16:30:00'),
('Mr. BEACH', '2011-01-07 16:00:00'),
('Mr. SCHAL', '2011-01-07 15:30:00'),
('Mr. ADAMS', '2011-01-07 15:00:00'),
('Mr. SCHAL', '2011-01-07 14:30:00'),
('Mr. JONES', '2011-01-07 14:00:00'),
('Mr. BEACH','2011-01-07 13:00:00')
SELECT T2.*
FROM
#Temp T2
INNER JOIN
(SELECT
A,
MAX(B) as MaxTime
FROM #Temp
group by A) as T1
ON T2.A=T1.A
order by T1.MaxTime desc, T2.B desc
A B
Mr. ADAMS2011-01-07 17:00:00.000
Mr. ADAMS2011-01-07 15:00:00.000
Mr. BEACH2011-01-07 16:30:00.000
Mr. BEACH2011-01-07 16:00:00.000
Mr. BEACH2011-01-07 13:00:00.000
Mr. SCHAL2011-01-07 15:30:00.000
Mr. SCHAL2011-01-07 14:30:00.000
Mr. JONES2011-01-07 14:00:00.000
January 7, 2011 at 2:12 pm
Mhlewis and mister.magoo, these both work. Thanks very much for the timely response.
D
Viewing 5 posts - 1 through 4 (of 4 total)
You must be logged in to reply to this topic. Login to reply