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 12»»

Difference between two date/times and flag each hour in between Expand / Collapse
Author
Message
Posted Tuesday, December 31, 2013 8:13 AM
SSC Rookie

SSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC Rookie

Group: General Forum Members
Last Login: Wednesday, August 27, 2014 9:55 AM
Points: 30, Visits: 120
I'm stumped!

I have a request where i would like to get the start date/time and end date/time and flag (with an int) which hours (24 hour clock) have values between the two dates. Example car comes into service on 2013-12-25 at 0800 and leaves 2013-12-25 at 1400 the difference is 6 hours and i need my table to show

Column: Hour_6 Value: 0
Column: Hour_7 Value: 0
Column: Hour_8 Value: 1
Column: Hour_9 Value: 1
Column: Hour_10 Value: 1
Column: Hour_11 Value: 1
Column: Hour_12 Value: 1
Column: Hour_13 Value: 1
Column: Hour_14 Value: 0

As i'm working away at it i'm trying to figure out how i could use a Time Dimension table for this but dont really see much.

So far i have the difference between the two times in hours (hour_diff) and the start hour (min_hour) so i would like to do something where i update the first hour (min_hour) and update columns based on the numbers of hours (hour_diff)

Advice on how i can go about this would be greatly appreciated ! Thank you and Happy New Years!
Post #1526757
Posted Tuesday, December 31, 2013 10:15 AM
SSC Rookie

SSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC Rookie

Group: General Forum Members
Last Login: Wednesday, August 13, 2014 10:19 AM
Points: 36, Visits: 238
Can you include table structure for your data describing when cars begin and end their service period? How those tables are laid out is going to have a pretty big impact on how best to get the result set you're after.

Edit: See this article for how best to frame your question.


blog: http://www.codemuddler.com
twitter: http://www.twitter.com/CodeMuddler
Post #1526797
Posted Tuesday, December 31, 2013 12:32 PM
SSChasing Mays

SSChasing MaysSSChasing MaysSSChasing MaysSSChasing MaysSSChasing MaysSSChasing MaysSSChasing MaysSSChasing Mays

Group: General Forum Members
Last Login: Tuesday, November 18, 2014 11:25 AM
Points: 637, Visits: 2,143
If you've already got a time dimension it should be be too hard from there.

First, a question, do you include an hour if the start is during that hour (same for end)?

For example, if it comes in at 0841, should the 8 oclock hour get a 1? If it leaves at 0901, should the 9 oclock hour get a 1?

What you are basically going to do is join to your time dimension based on the two dates, grouping based on hours. But the particulars come down to your table definitions and your requirements (hence the question above)
Post #1526834
Posted Tuesday, December 31, 2013 12:47 PM
SSC Rookie

SSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC Rookie

Group: General Forum Members
Last Login: Wednesday, August 27, 2014 9:55 AM
Points: 30, Visits: 120
Thanks for the replies i did figure it out and used my time dimension, below is the code for those wondering:

select distinct t.visit_date,t.car_id,t.car_color,d.hour_of_day_24
from TABLE t
inner join DIMENSION d
on d.string_representation_24 between t.car_start_date and t.car_end_date

the answer to the question above is yes both 0800 get a 1 and 0900 gets 1 regardless if the car was there for an hour. I am trying to capture volume by hour. That is only half of the request the next half will be challenging as well.
Post #1526838
Posted Thursday, January 2, 2014 8:54 AM
SSC Rookie

SSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC Rookie

Group: General Forum Members
Last Login: Wednesday, August 27, 2014 9:55 AM
Points: 30, Visits: 120
well i found a bug with the code posted and that is it doesn't include records that stay longer than a day...
so back to square one.
Post #1527169
Posted Thursday, January 2, 2014 12:38 PM


SSC Veteran

SSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC Veteran

Group: General Forum Members
Last Login: 2 days ago @ 1:06 PM
Points: 210, Visits: 970
You didn't give much to work with, but here's an example of how I'd do this given your dimTime table is similar to ones I usually use. Also I'm using the [Whatever] table to denote occurrences during specific times:

-- Setup Whatever Table
CREATE TABLE Whatever (TimeDateKey DATETIME, Occurrence INTEGER);
INSERT INTO Whatever (TimeDateKey, Occurrence) VALUES
('2013-12-25 09:11',1),
('2013-12-25 10:15',1),
('2013-12-25 10:44',1),
('2013-12-25 11:43',1)

-- Setup Time Dimention
DECLARE @TimeLoop TIME = '00:01'
CREATE TABLE dimTime (TimeKey TIME, TimeHour INTEGER, TimeMinute INTEGER, PartOfDay CHAR(2))
INSERT INTO dimTime (TimeKey, TimeHour, TimeMInute, PartofDay) VALUES ('00:00',0,0,'AM')
WHILE @TimeLoop <> '00:00'
BEGIN
INSERT INTO dimTime (TimeKey, TimeHour, TimeMInute, PartofDay) VALUES (
@TimeLoop,
DATEPART(HOUR,@TimeLoop),
DATEPART(Minute,@TimeLoop),
CASE WHEN @TimeLoop < '12:00' THEN 'AM' ELSE 'PM' END)

SET @TimeLoop = DATEADD(Minute,1,@TimeLoop)
END

-- Query
DECLARE @StartTime DATETIME = '2013-12-25 08:00',
@EndTime DATETIME = '2013-12-25 14:00';

WITH OutputTable ([Hours],[Occurrences]) as (
SELECT 'Hour_' + RIGHT('0' + CONVERT(VARCHAR(2),t.TimeHour),2) AS [Hours],
COUNT(w.Occurrence) as [Occurrences]
FROM dimTime t
LEFT OUTER JOIN Whatever w ON
DATEPART(hour,w.TimeDateKey) = t.TimeHour
WHERE t.TimeHour BETWEEN DATEPART(HOUR,@StartTime) AND DATEPART(HOUR,@EndTime) AND
t.TimeMinute = 0
GROUP BY 'Hour_' + RIGHT('0' + CONVERT(VARCHAR(2),t.TimeHour),2))
SELECT [Hours],
CASE WHEN [Occurrences] = 0 THEN 0 ELSE 1 END AS [Occurrences]
FROM OutputTable

-- Cleanup
DROP TABLE Whatever
DROP TABLE dimTime



The output will be this:
Hours Occurrences
Hour_08 0
Hour_09 1
Hour_10 1
Hour_11 1
Hour_12 0
Hour_13 0
Hour_14 0
Post #1527257
Posted Thursday, January 2, 2014 1:09 PM
SSC Rookie

SSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC Rookie

Group: General Forum Members
Last Login: Wednesday, August 27, 2014 9:55 AM
Points: 30, Visits: 120
Hi salamex,

Thank you, this query is very similar to my first query and it works great if the car is in "service/shop" on the same day, the problem i ran into after doing some validation is that it excludes cars that span more than one day.

That is because the "between" join doesn't work example:

same day : 08:00 - 13:00 (8,9,10,11,12,13)
different day: 21:00 - 03:00 (null)

i think i'll just need to do 2 queries but still working it out.
Post #1527265
Posted Thursday, January 2, 2014 6:57 PM


Hall of Fame

Hall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of Fame

Group: General Forum Members
Last Login: Monday, November 24, 2014 4:53 AM
Points: 3,422, Visits: 5,368
I'm not sure if this is exactly what you want but you might want to look at it and see if it gives you some ideas.

WITH SampleData (ID, SDT, EDT) AS
(
SELECT 1, CAST('2013-12-25 08:00' AS DATETIME), CAST('2013-12-25 13:00' AS DATETIME)
UNION ALL SELECT 2, CAST('2013-12-25 10:00' AS DATETIME), CAST('2013-12-26 12:00' AS DATETIME)
),
Tally (n) AS
(
SELECT ROW_NUMBER() OVER (ORDER BY (SELECT NULL))
FROM (VALUES (0),(0),(0),(0),(0),(0)) a (n)
CROSS JOIN (VALUES (0),(0),(0),(0)) b (n)
)
SELECT HourOfDay=n, CountOfCars=SUM(flag)
FROM (
SELECT n
,flag=CASE WHEN std = d AND ed = d AND n BETWEEN DATEPART(hour, SDT) AND DATEPART(hour, EDT) THEN 1
WHEN std = d AND ed <> d AND DATEPART(hour, SDT) >= n THEN 1
WHEN ed = d AND std <> d AND DATEPART(hour, EDT) <= n THEN 1
WHEN d NOT IN (std, ed) THEN 1
ELSE 0
END
FROM SampleData a
CROSS APPLY
(
SELECT TOP (1+DATEDIFF(day, SDT, EDT))
d=DATEADD(day, DATEDIFF(day, 0, SDT), n-1)
,std=DATEADD(day, DATEDIFF(day, 0, SDT), 0)
,ed=DATEADD(day, DATEDIFF(day, 0, EDT), 0)
FROM Tally
) b
CROSS APPLY Tally c
WHERE n IN (6,7,8,9,10,11,12,13,14)
) a
GROUP BY n;


If your car can be in the shop for more than 24 days, you'll need a bigger Tally table.



My mantra: No loops! No CURSORs! No RBAR! Hoo-uh!

My thought question: Have you ever been told that your query runs too fast?

My advice:
INDEXing a poor-performing query is like putting sugar on cat food. Yeah, it probably tastes better but are you sure you want to eat it?
The path of least resistance can be a slippery slope. Take care that fixing your fixes of fixes doesn't snowball and end up costing you more than fixing the root cause would have in the first place.


Need to UNPIVOT? Why not CROSS APPLY VALUES instead?
Since random numbers are too important to be left to chance, let's generate some!
Learn to understand recursive CTEs by example.
Splitting strings based on patterns can be fast!
Post #1527333
Posted Friday, January 3, 2014 7:11 AM


SSCertifiable

SSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiable

Group: General Forum Members
Last Login: Yesterday @ 6:52 AM
Points: 6,872, Visits: 14,185
cs_source (1/2/2014)
Hi salamex,

Thank you, this query is very similar to my first query and it works great if the car is in "service/shop" on the same day, the problem i ran into after doing some validation is that it excludes cars that span more than one day.

That is because the "between" join doesn't work example:

same day : 08:00 - 13:00 (8,9,10,11,12,13)
different day: 21:00 - 03:00 (null)

i think i'll just need to do 2 queries but still working it out.


A little sample data would go a long way.


“Write the query the simplest way. If through testing it becomes clear that the performance is inadequate, consider alternative query forms.” - Gail Shaw

For fast, accurate and documented assistance in answering your questions, please read this article.
Understanding and using APPLY, (I) and (II) Paul White
Hidden RBAR: Triangular Joins / The "Numbers" or "Tally" Table: What it is and how it replaces a loop Jeff Moden
Exploring Recursive CTEs by Example Dwain Camps
Post #1527518
Posted Friday, January 3, 2014 7:57 AM
SSC Rookie

SSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC Rookie

Group: General Forum Members
Last Login: Wednesday, August 27, 2014 9:55 AM
Points: 30, Visits: 120
Thank you dwain.c, i'm working through the query now to under stand it (pretty complicated :)

hi Chris.m below is the sample data as well as my expected output (sorry i should have provided this earlier)

CREATE TABLE [dbo].[sampleA](
[visit_date] [date] NULL,
[enter_datetime] [datetime] NULL,
[depart_datetime] [datetime] NULL,
[vin] [int] NULL,
[make] [char](10) NULL
) ON [PRIMARY]


INSERT INTO [sampleA]
([visit_date]
,[enter_datetime]
,[depart_datetime]
,[vin]
,[make])
VALUES
('2011-01-01','2011-01-01 23:00','2011-01-02 1:35','222','vw'),
('2012-01-08','2012-01-08 22:30','2012-01-11 17:01','333','honda'),
('2013-12-25','2013-12-25 0:10','2013-12-25 2:25','111','ford')
GO

--DROP TABLE SampleA

Expected output (i insert these into another table for further manipulation:)

visit_date VIN make Hour_in_service
12/25/2013 111 ford 0
12/25/2013 111 ford 1
12/25/2013 111 ford 2
1/1/2011 222 vw 23
1/2/2011 222 vw 0
1/2/2011 222 vw 1
1/8/2012 333 honda 22
1/8/2012 333 honda 23
1/9/2012 333 honda 0
1/9/2012 333 honda 1
1/9/2012 333 honda 2
1/9/2012 333 honda 3
1/9/2012 333 honda 4
1/9/2012 333 honda 5
1/9/2012 333 honda 6
1/9/2012 333 honda 7
1/9/2012 333 honda 8
1/9/2012 333 honda 9
1/9/2012 333 honda 10
1/9/2012 333 honda 11
1/9/2012 333 honda 12
1/9/2012 333 honda 13
1/9/2012 333 honda 14
1/9/2012 333 honda 15
1/9/2012 333 honda 16
1/9/2012 333 honda 17
1/9/2012 333 honda 18
1/9/2012 333 honda 19
1/9/2012 333 honda 20
1/9/2012 333 honda 21
1/9/2012 333 honda 22
1/9/2012 333 honda 23
1/10/2012 333 honda 0
1/10/2012 333 honda 1
1/10/2012 333 honda 2
1/10/2012 333 honda 3
1/10/2012 333 honda 4
1/10/2012 333 honda 5
1/10/2012 333 honda 6
1/10/2012 333 honda 7
1/10/2012 333 honda 8
1/10/2012 333 honda 9
1/10/2012 333 honda 10
1/10/2012 333 honda 11
1/10/2012 333 honda 12
1/10/2012 333 honda 13
1/10/2012 333 honda 14
1/10/2012 333 honda 15
1/10/2012 333 honda 16
1/10/2012 333 honda 17
1/10/2012 333 honda 18
1/10/2012 333 honda 19
1/10/2012 333 honda 20
1/10/2012 333 honda 21
1/10/2012 333 honda 22
1/10/2012 333 honda 23
1/11/2012 333 honda 0
1/11/2012 333 honda 1
1/11/2012 333 honda 2
1/11/2012 333 honda 3
1/11/2012 333 honda 4
1/11/2012 333 honda 5
1/11/2012 333 honda 6
1/11/2012 333 honda 7
1/11/2012 333 honda 8
1/11/2012 333 honda 9
1/11/2012 333 honda 10
1/11/2012 333 honda 11
1/11/2012 333 honda 12
1/11/2012 333 honda 14
1/11/2012 333 honda 15
1/11/2012 333 honda 16
1/11/2012 333 honda 17
Post #1527548
« Prev Topic | Next Topic »

Add to briefcase 12»»

Permissions Expand / Collapse