| Author |
Topic |
|
PeterNeo
Constraint Violating Yak Guru
357 Posts |
Posted - 2007-06-12 : 09:50:49
|
| Hi,I have strange requirement.Declare @t table ( id int, time varchra(10), patient int, check int )Insert into @tSelect 1, '7:00AM', 1, 1 Union allSelect 2, '7:30AM', 1, 2 Union allSelect 3, '8:00AM', 1, 3 Union allSelect 4, '8:30AM', null, null Union allSelect 5, '9:00AM', 2, 1 Union allSelect 6, '7:00AM', 2, 2 Now my desired output is1, '7:00AM', 1, 1, "1,2,3"2, '7:30AM', 1, 2, "1,2,3"3, '8:00AM', 1, 3, "1,2,3"4, '8:30AM', null, null, null,5, '9:00AM', 2, 1, "1,2"6, '7:00AM', 2, 2, "1,2"Thanks in advance |
|
|
nr
SQLTeam MVY
12543 Posts |
Posted - 2007-06-12 : 10:26:58
|
| You need to concatenate the check's which can't be done without a function or loop unless you have a limit on the number.This is for the function which means a table rather than temp table.create table t ( id int, time varchar(10), patient int, [check] int )Insert into tSelect 1, '7:00AM', 1, 1 Union allSelect 2, '7:30AM', 1, 2 Union allSelect 3, '8:00AM', 1, 3 Union allSelect 4, '8:30AM', null, null Union allSelect 5, '9:00AM', 2, 1 Union allSelect 6, '7:00AM', 2, 2 create function fn_concatpatients(@minid int ,@maxid int )returns varchar(1000)asbegindeclare @s varchar(1000)select @s = coalesce(@s+',','') + convert(varchar(10),[check])from twhere id between @minid and @maxidreturn @sendgoselect t.id, t.time, t.Patient, t.[check], dbo.fn_concatpatients(t2.minid, t2.maxid)from t tjoin(select minid = min(id), maxid = max(id) from(select t.id, grp = (select count(distinct coalesce(patient,-1)) from t t2 where t2.id <= t.id)from t t) t group by grp) t2on t.id between t2.minid and t2.maxid==========================================Cursors are useful if you don't know sql.DTS can be used in a similar way.Beer is not cold and it isn't fizzy. |
 |
|
|
pbguy
Constraint Violating Yak Guru
319 Posts |
Posted - 2007-06-13 : 00:16:31
|
| t2 derived query can be replaced withSelect min([id]) as minid, max([id]) as maxid from tgroup by patient--------------------------------------------------S.Ahamed |
 |
|
|
nr
SQLTeam MVY
12543 Posts |
Posted - 2007-06-13 : 10:00:42
|
quote: Originally posted by pbguy t2 derived query can be replaced withSelect min([id]) as minid, max([id]) as maxid from tgroup by patient--------------------------------------------------S.Ahamed
Not it can't - if the same patient left and came back later in the day that query would show that they had never left.==========================================Cursors are useful if you don't know sql.DTS can be used in a similar way.Beer is not cold and it isn't fizzy. |
 |
|
|
|
|
|