December 31, 2013 at 8:13 am
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!
December 31, 2013 at 10:15 am
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[/url] for how best to frame your question.
blog: http://www.codemuddler.com
twitter: http://www.twitter.com/CodeMuddler
December 31, 2013 at 12:32 pm
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)
December 31, 2013 at 12:47 pm
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.
January 2, 2014 at 8:54 am
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.
January 2, 2014 at 12:38 pm
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]
FROMdimTime t
LEFT OUTER JOIN Whatever w ON
DATEPART(hour,w.TimeDateKey) = t.TimeHour
WHEREt.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]
FROMOutputTable
-- Cleanup
DROP TABLE Whatever
DROP TABLE dimTime
The output will be this:
Hours Occurrences
Hour_08 0
Hour_091
Hour_101
Hour_111
Hour_120
Hour_130
Hour_140
January 2, 2014 at 1:09 pm
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.
January 2, 2014 at 6:57 pm
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 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?[/url]
Since random numbers are too important to be left to chance, let's generate some![/url]
Learn to understand recursive CTEs by example.[/url]
[url url=http://www.sqlservercentral.com/articles/St
January 3, 2014 at 7:11 am
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.
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
January 3, 2014 at 7:57 am
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/2013111ford 0
12/25/2013111ford 1
12/25/2013111ford 2
1/1/2011222vw 23
1/2/2011222vw 0
1/2/2011222vw 1
1/8/2012333honda22
1/8/2012333honda23
1/9/2012333honda0
1/9/2012333honda1
1/9/2012333honda2
1/9/2012333honda3
1/9/2012333honda4
1/9/2012333honda5
1/9/2012333honda6
1/9/2012333honda7
1/9/2012333honda8
1/9/2012333honda9
1/9/2012333honda10
1/9/2012333honda11
1/9/2012333honda12
1/9/2012333honda13
1/9/2012333honda14
1/9/2012333honda15
1/9/2012333honda16
1/9/2012333honda17
1/9/2012333honda18
1/9/2012333honda19
1/9/2012333honda20
1/9/2012333honda21
1/9/2012333honda22
1/9/2012333honda23
1/10/2012333honda0
1/10/2012333honda1
1/10/2012333honda2
1/10/2012333honda3
1/10/2012333honda4
1/10/2012333honda5
1/10/2012333honda6
1/10/2012333honda7
1/10/2012333honda8
1/10/2012333honda9
1/10/2012333honda10
1/10/2012333honda11
1/10/2012333honda12
1/10/2012333honda13
1/10/2012333honda14
1/10/2012333honda15
1/10/2012333honda16
1/10/2012333honda17
1/10/2012333honda18
1/10/2012333honda19
1/10/2012333honda20
1/10/2012333honda21
1/10/2012333honda22
1/10/2012333honda23
1/11/2012333honda0
1/11/2012333honda1
1/11/2012333honda2
1/11/2012333honda3
1/11/2012333honda4
1/11/2012333honda5
1/11/2012333honda6
1/11/2012333honda7
1/11/2012333honda8
1/11/2012333honda9
1/11/2012333honda10
1/11/2012333honda11
1/11/2012333honda12
1/11/2012333honda14
1/11/2012333honda15
1/11/2012333honda16
1/11/2012333honda17
January 3, 2014 at 8:01 am
cs_source (1/3/2014)
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)
...
Thanks! Yes that's great. It makes things so much easier.
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
January 3, 2014 at 8:27 am
;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
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
January 3, 2014 at 8:59 am
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 ๐ 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
January 3, 2014 at 9:59 am
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 ๐ 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
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
January 17, 2014 at 9:29 am
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?
Viewing 15 posts - 1 through 15 (of 16 total)
You must be logged in to reply to this topic. Login to reply