SQL Clone
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


Difference between two date/times and flag each hour in between


Difference between two date/times and flag each hour in between

Author
Message
ChrisM@Work
ChrisM@Work
SSC-Forever
SSC-Forever (41K reputation)SSC-Forever (41K reputation)SSC-Forever (41K reputation)SSC-Forever (41K reputation)SSC-Forever (41K reputation)SSC-Forever (41K reputation)SSC-Forever (41K reputation)SSC-Forever (41K reputation)

Group: General Forum Members
Points: 41757 Visits: 20006
cs_source (1/3/2014)
Thank you dwain.c, i'm working through the query now to under stand it (pretty complicated Smile

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

...


Thanks! Yes that's great. It makes things so much easier.

“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
ChrisM@Work
ChrisM@Work
SSC-Forever
SSC-Forever (41K reputation)SSC-Forever (41K reputation)SSC-Forever (41K reputation)SSC-Forever (41K reputation)SSC-Forever (41K reputation)SSC-Forever (41K reputation)SSC-Forever (41K reputation)SSC-Forever (41K reputation)

Group: General Forum Members
Points: 41757 Visits: 20006
;WITH 
[4] AS (SELECT n = 0 FROM (VALUES (0), (0), (0), (0)) d (n)),
[16] AS (SELECT n = 0 FROM [4] a, [4] b),
[256] AS (SELECT n = 0 FROM [16] a, [16] b),
[65536] AS (SELECT n = 0 FROM [256] a, [256] b),
iTally AS (SELECT n = ROW_NUMBER() OVER(ORDER BY (SELECT NULL))-1 FROM [65536] a, [16] b)

SELECT a.visit_date, a.vin, a.make, x.Hour_in_service
FROM #sampleA a
CROSS APPLY (
SELECT TOP (1 + DATEDIFF(hour, a.enter_datetime, a.depart_datetime))
Hour_in_service = DATEPART(HOUR,DATEADD(hour,n,a.enter_datetime))
FROM iTally t
) x



“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
cs_source
cs_source
SSC Veteran
SSC Veteran (263 reputation)SSC Veteran (263 reputation)SSC Veteran (263 reputation)SSC Veteran (263 reputation)SSC Veteran (263 reputation)SSC Veteran (263 reputation)SSC Veteran (263 reputation)SSC Veteran (263 reputation)

Group: General Forum Members
Points: 263 Visits: 185
okay, wow well thank you all for your queries, i learnt something new with each one, the last query outputs the data in the format i'm exactly looking for Smile so thank you,

2 quick questions:

1 - if i want the visit date reflected with the date the hours fall under is that another query where i update the table that this data will go into?

2 - breaking down the query so i understand it more, whats going on is:

creating 4 cte tables
populating them with ascending integers
select the data and cross apply
its the second half of the query that i'm trying to wrap my head around:

SELECT TOP (1 + DATEDIFF(hour, a.enter_datetime, a.depart_datetime))
-- This gets the difference in hours for each enter/depart time and top 1 signals ?? when i remove the 1 i lose a record when i add the 1 i gain a record

Hour_in_service = DATEPART(HOUR,DATEADD(hour,n,a.enter_datetime))
-- a little confused here how n plays a role with the enter time
FROM iTally t
ChrisM@Work
ChrisM@Work
SSC-Forever
SSC-Forever (41K reputation)SSC-Forever (41K reputation)SSC-Forever (41K reputation)SSC-Forever (41K reputation)SSC-Forever (41K reputation)SSC-Forever (41K reputation)SSC-Forever (41K reputation)SSC-Forever (41K reputation)

Group: General Forum Members
Points: 41757 Visits: 20006
cs_source (1/3/2014)
okay, wow well thank you all for your queries, i learnt something new with each one, the last query outputs the data in the format i'm exactly looking for Smile so thank you,


You're welcome


2 quick questions:

1 - if i want the visit date reflected with the date the hours fall under is that another query where i update the table that this data will go into?


Easiest way to answer this is if you can post it as expected output. A picture tells etc etc


2 - breaking down the query so i understand it more, whats going on is:

creating 4 cte tables

CTE's aren't tables. They're more or less views built on the fly, kinda like macro's.

populating them with ascending integers
select the data and cross apply
its the second half of the query that i'm trying to wrap my head around:

SELECT TOP (1 + DATEDIFF(hour, a.enter_datetime, a.depart_datetime))
-- This gets the difference in hours for each enter/depart time and top 1 signals ?? when i remove the 1 i lose a record when i add the 1 i gain a record

Hour_in_service = DATEPART(HOUR,DATEADD(hour,n,a.enter_datetime))
-- a little confused here how n plays a role with the enter time
FROM iTally t


Have a look at Jeff's Tally Tables article, currently on the hotlist.

Edited to fix tags

“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
cs_source
cs_source
SSC Veteran
SSC Veteran (263 reputation)SSC Veteran (263 reputation)SSC Veteran (263 reputation)SSC Veteran (263 reputation)SSC Veteran (263 reputation)SSC Veteran (263 reputation)SSC Veteran (263 reputation)SSC Veteran (263 reputation)

Group: General Forum Members
Points: 263 Visits: 185
hi again,

i dont mean to bump this thread up again but the output was great for the use and additional scope has been added. To use a graphing tool that we have (to display the data) i need to get the data into a single column based on which column has a value entered

example

hour_detail| hour1| hour2|hour3| hour4| hour5
5 | 0| 0| 0| 0| 5
2 | 0| 2| 0| 0| 0
3 | 0| 0| 3| 0| 0
1 | 1| 0| 0| 0| 0
4 | 0| 0| 0| 4| 0

I thought about create a massive case statement but i dont think that was correct, i also look at Coalesce but i think have too man columns to preform this as well as i have 0's and not nulls ? I have 23 columns across.

what is some advice on how i can proceed to do this?
ChrisM@Work
ChrisM@Work
SSC-Forever
SSC-Forever (41K reputation)SSC-Forever (41K reputation)SSC-Forever (41K reputation)SSC-Forever (41K reputation)SSC-Forever (41K reputation)SSC-Forever (41K reputation)SSC-Forever (41K reputation)SSC-Forever (41K reputation)

Group: General Forum Members
Points: 41757 Visits: 20006
This looks like the output from a CROSSTAB query. If so, you would normally aggregate across whatever the partition is and use MAX() on each column value. Post your query if you are unsure.

“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
cs_source
cs_source
SSC Veteran
SSC Veteran (263 reputation)SSC Veteran (263 reputation)SSC Veteran (263 reputation)SSC Veteran (263 reputation)SSC Veteran (263 reputation)SSC Veteran (263 reputation)SSC Veteran (263 reputation)SSC Veteran (263 reputation)

Group: General Forum Members
Points: 263 Visits: 185
Hi ChrisM@work and others!

It seems that the output from this query was great for the customers and now they are asking to expand it and once again i would like to ask for assistance.

The query does a great job of tracking the hours between two dates so i can capture at which hours a car was serviced in the day. The answer to my question (was answered by ChrisM@Work, thank you sir) works great and now i need it expanded into listing days along with the hours.

Data Example:
Mazda
In Shop Date: 2014-07-01
In Shop Time: 22:00
Out Shop Date: 2014-07-02
Out Shop Time: 03:00

This output would look as follows:

date |h0|h1|h2|h3|h4|h5|h6|h7|h8|h9|h10|h11|h12|h13|h14|h15|h16|h17|h18|h19|h20|h21|h22|h23
2014-07-01 1
2014-07-01 1
2014-07-02 1
2014-07-02 1
2014-07-02 1

The code that i have used again was:
;WITH
[4] AS (SELECT n = 0 FROM (VALUES (0), (0), (0), (0)) d (n)),
[16] AS (SELECT n = 0 FROM [4] a, [4] b),
[256] AS (SELECT n = 0 FROM [16] a, [16] b),
[65536] AS (SELECT n = 0 FROM [256] a, [256] b),
[4294967296] AS (SELECT n = 0 FROM [65536] a, [65536] b),
iTally AS (SELECT n = ROW_NUMBER() OVER(ORDER BY (SELECT NULL))-1 FROM [4294967296] a, [16] b)
INSERT INTO Shop_log
(visit_date
,h0
,h1
...etc)
SELECT
??? <- field i am trying to capture (before it was just the In Shop Date but the records would show same date)
,h0
,h1
..etc
from CARS a
CROSS APPLY (
SELECT TOP (1+ DATEDIFF(hour, a.In_Shop_Date, a.Out_Shop_Date))
Hour_in_service = DATEPART(HOUR,DATEADD(hour,n,a.In_Shop_Date))
FROM iTally t
) x

Much appreciated
Go


Permissions

You can't post new topics.
You can't post topic replies.
You can't post new polls.
You can't post replies to polls.
You can't edit your own topics.
You can't delete your own topics.
You can't edit other topics.
You can't delete other topics.
You can't edit your own posts.
You can't edit other posts.
You can't delete your own posts.
You can't delete other posts.
You can't post events.
You can't edit your own events.
You can't edit other events.
You can't delete your own events.
You can't delete other events.
You can't send private messages.
You can't send emails.
You can read topics.
You can't vote in polls.
You can't upload attachments.
You can download attachments.
You can't post HTML code.
You can't edit HTML code.
You can't post IFCode.
You can't post JavaScript.
You can post emoticons.
You can't post or upload images.

Select a forum

































































































































































SQLServerCentral


Search