September 10, 2009 at 2:59 pm
Here is a real stumper:
I have a single row coming out of a table:
Name Date Hours Sec
--------------------------------------------------------
Sam 09/10/2009 15:20:39.000 3 11024
I need to represent this row in the following format:
Name Date Sec
-------------------------------------------------
Sam 09/10/2009 12:00:00.000 2585
Sam 09/10/2009 13:00:00.000 3600
Sam 09/10/2009 14:00:00.000 3600
Sam 09/10/2009 15:00:00.000 1239
Does anyone have ideas of how I can achieve this without a cursor or while loop?
This only reflects a single original row; but the original row can return many names with their data.
Thanks!
September 10, 2009 at 4:04 pm
use testing
select 'Sam' name1, '09/10/2009 15:20:39.000' endts, 3 unk, 11024 duration
into #matt
go
;with MattCTE as (
select datediff(second,dateadd(hour,datediff(hour,0,endts),0),endts) basesecs,
dateadd(hour,datediff(hour,0,endts),0) basehour,
*
from #matt)
select
case when (duration-basesecs-(n-1)*3600)>3600 then 3600 else (duration-basesecs-(n-1)*3600) end secsspent,
dateadd(hour,(-1*n),basehour) timeslice,
endts,unk,duration from MattCTE
inner join tally on duration-basesecs-(n-1)*3600>0
where n<10
UNION ALL
select case when duration<basesecs then duration else basesecs end secsspent,
basehour timeslice,
endts,unk,duration
from mattCTE
ORDER by timeslice desc
Try this on....
----------------------------------------------------------------------------------
Your lack of planning does not constitute an emergency on my part...unless you're my manager...or a director and above...or a really loud-spoken end-user..All right - what was my emergency again?
September 10, 2009 at 4:27 pm
My immensely more confusing (but 2000 compliant) solution. I'm sure I could make this much less confusing and likely more efficient.
DECLARE @a TABLE(
NAMEVARCHAR(20),
dateDATETIME,
hoursINT,
secondsBIGINT)
insert INTO @a
SELECT 'Sam', '09/10/2009 15:20:39.000', 3, 11024 UNION ALL
SELECT 'Mary', '09/10/2009 13:26:19.000', 3, 18439 UNION ALL
SELECT 'Beth', '09/10/2009 4:16:22.000', 2, 8439
SELECT NAME,
DATEADD(hh,-(N-1),DATEADD(hh, DATEDIFF(hh,0,[date]),0)),
CASE WHEN N = 1 THEN DATEDIFF(s,(DATEADD(hh, DATEDIFF(hh,0,[date]), 0)),[date])
WHEN N > 1 AND DATEDIFF(s,(DATEADD(hh, DATEDIFF(hh,0,[date]), 0)),[date]) + ((N-1) * 3600) < seconds
THEN 3600
ELSE seconds - (DATEDIFF(s,(DATEADD(hh, DATEDIFF(hh,0,[date]), 0)),[date]) + ((N-2) * 3600))
END
Seconds
FROM @a, tally
WHERE (N-1)*3600 1 AND DATEDIFF(s,basehour,[date]) + ((N-1) * 3600) < seconds
THEN 3600
ELSE seconds - (DATEDIFF(s,basehour,[date]) + ((N-2) * 3600))
END
Seconds
FROM @a, tally
WHERE (N-1)*3600 < seconds
ORDER BY NAME,
DATEADD(hh,-(N-1),Basehour) DESC
September 11, 2009 at 1:55 am
John,
Both solutions above use a wonderful little tool known as a "Tally" or "Numbers" table. To see how to build one as well as a detailed explanation as to how they work and how they can be used to replace a While loop in a high speed fashion, please see the following article...
http://www.sqlservercentral.com/articles/T-SQL/62867/
--Jeff Moden
Change is inevitable... Change for the better is not.
Viewing 4 posts - 1 through 3 (of 3 total)
You must be logged in to reply to this topic. Login to reply