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


Time Range


Time Range

Author
Message
stergiazotali
stergiazotali
Grasshopper
Grasshopper (23 reputation)Grasshopper (23 reputation)Grasshopper (23 reputation)Grasshopper (23 reputation)Grasshopper (23 reputation)Grasshopper (23 reputation)Grasshopper (23 reputation)Grasshopper (23 reputation)

Group: General Forum Members
Points: 23 Visits: 58
Hello Everyone,

I am having difficulties to display data between 22:00 and 05:59.

So the following query is generally working except for the above time range :

select TOP(1) CONVERT(DECIMAL(18,2),REPLACE(CONVERT(VARCHAR(5),CONVERT(DATETIME,EndTime),108),':','.'))-CONVERT(DECIMAL(18,2),REPLACE(CONVERT(VARCHAR(5),CONVERT(DATETIME,@DAte),108),':','.'))
FROM ProductionShift WHERE CAST(@date AS time(5))
BETWEEN
CAST(replace(convert(varchar,@date,110),'/','-')+' '+StartTime+':00.000' AS time(5)) AND CAST(replace(convert(varchar,@date,110),'/','-')+' '+EndTime+':00.000' AS time(5))



The columns StartTime and EndTime are varchars(ie 06:00, 13:59)!They can't be changed. My thought was to short of 'construct' the date so can check the range properly. Like I mentioned, it works for all the shifts EXCEPT the night one!!



Any help, would be really appreciated.

Thanks,
V
Jack Corbett
  Jack Corbett
SSCoach
SSCoach (19K reputation)SSCoach (19K reputation)SSCoach (19K reputation)SSCoach (19K reputation)SSCoach (19K reputation)SSCoach (19K reputation)SSCoach (19K reputation)SSCoach (19K reputation)

Group: General Forum Members
Points: 19284 Visits: 14900
Here's an example that shows what is probably happening to you:

DECLARE @ProductionShift TABLE
(
StartTime VARCHAR(10),
EndTime VARCHAR(10)
);
DECLARE @date DATETIME = '2013-09-09 02:30'
INSERT INTO @ProductionShift
(StartTime, EndTime)
VALUES
('22:00', -- StartTime - varchar(10)
'05:59' -- EndTime - varchar(10)
);
WITH dates
AS (
SELECT TOP (1)
CAST(REPLACE(CONVERT(VARCHAR, @date, 110), '/', '-') + ' ' + StartTime + ':00.000' AS TIME(5)) AS StartTime,
CAST(REPLACE(CONVERT(VARCHAR, @date, 110), '/', '-') + ' ' + EndTime + ':00.000' AS TIME(5)) AS EndTime,
CAST(@date AS TIME(5)) AS theDate
FROM
@ProductionShift
)
SELECT
*,
CASE WHEN dates.theDate BETWEEN dates.StartTime AND dates.EndTime THEN 1
ELSE 0
END AS isBetween
FROM
dates



Here's one way to get it to work:

DECLARE @ProductionShift TABLE
(
StartTime VARCHAR(10),
EndTime VARCHAR(10)
);
DECLARE @date DATETIME = '2013-09-09 02:30'
INSERT INTO @ProductionShift
(StartTime, EndTime)
VALUES
('22:00', -- StartTime - varchar(10)
'05:59' -- EndTime - varchar(10)
);
WITH dates
AS (
SELECT TOP (1)
CAST(REPLACE(CONVERT(VARCHAR, @date, 110), '/', '-') + ' ' + StartTime + ':00.000' AS DATETIME) AS StartTime,
CAST(REPLACE(CONVERT(VARCHAR, @date, 110), '/', '-') + ' ' + EndTime + ':00.000' AS DATETIME) AS EndTime,
CAST(@date AS TIME(5)) AS theDate
FROM
@ProductionShift
),
correctedDates
AS (
SELECT
*,
CASE WHEN startTime > EndTime THEN DATEADD(DAY, -1, STArtTIme)
ELSE STARTTIME
END AS newStartTIme
FROM
dates
)
SELECT
*
FROM
correctedDates
WHERE
@date BETWEEN correctedDates.newStartTIme
AND correctedDates.EndTime





Jack Corbett

Applications Developer

Don't let the good be the enemy of the best. -- Paul Fleming
At best you can say that one job may be more secure than another, but total job security is an illusion. -- Rod at work

Check out these links on how to get faster and more accurate answers:
Forum Etiquette: How to post data/code on a forum to get the best help
Need an Answer? Actually, No ... You Need a Question
How to Post Performance Problems
Crosstabs and Pivots or How to turn rows into columns Part 1
Crosstabs and Pivots or How to turn rows into columns Part 2
Sean Pearce
Sean Pearce
SSCommitted
SSCommitted (1.8K reputation)SSCommitted (1.8K reputation)SSCommitted (1.8K reputation)SSCommitted (1.8K reputation)SSCommitted (1.8K reputation)SSCommitted (1.8K reputation)SSCommitted (1.8K reputation)SSCommitted (1.8K reputation)

Group: General Forum Members
Points: 1824 Visits: 3432
If your end time is in the next day you will need to add a day to your date parameter.

WHERE MyDate BETWEEN CAST(@date + StartTime) AND CAST(DATEADD(DAY, 1, @date) + EndTime)



disclaimer: the above is pseudo-code for readability



The SQL Guy @ blogspot

@SeanPearceSQL

About Me
stergiazotali
stergiazotali
Grasshopper
Grasshopper (23 reputation)Grasshopper (23 reputation)Grasshopper (23 reputation)Grasshopper (23 reputation)Grasshopper (23 reputation)Grasshopper (23 reputation)Grasshopper (23 reputation)Grasshopper (23 reputation)

Group: General Forum Members
Points: 23 Visits: 58
many thanks for the reply,

I have been trying for hours to understand the problem. I will try and let you know.

Thanks
stergiazotali
stergiazotali
Grasshopper
Grasshopper (23 reputation)Grasshopper (23 reputation)Grasshopper (23 reputation)Grasshopper (23 reputation)Grasshopper (23 reputation)Grasshopper (23 reputation)Grasshopper (23 reputation)Grasshopper (23 reputation)

Group: General Forum Members
Points: 23 Visits: 58
It worked. Thanks guys!
Dennis Post
Dennis Post
SSC-Addicted
SSC-Addicted (407 reputation)SSC-Addicted (407 reputation)SSC-Addicted (407 reputation)SSC-Addicted (407 reputation)SSC-Addicted (407 reputation)SSC-Addicted (407 reputation)SSC-Addicted (407 reputation)SSC-Addicted (407 reputation)

Group: General Forum Members
Points: 407 Visits: 547
Here's another method.

DECLARE @Start   Varchar(5) = '07:00',
@End Varchar(5) = '05:59'

SELECT CASE
WHEN REPLACE(@Start, ':', '') < REPLACE(@End, ':','')
THEN DATEDIFF(HH, CAST('1900-01-01 '+ @Start AS SmallDateTime), CAST('1900-01-01 ' + @End AS SmallDateTime)) + 1
WHEN REPLACE(@Start, ':', '') > REPLACE(@End, ':','')
THEN DATEDIFF(HH, CAST('1900-01-01 '+ @Start AS SmallDateTime), CAST('1900-01-02 ' + @End AS SmallDateTime)) + 1
END



I don't know if you want the difference in minutes or hours, but I assumed hours. Other wise change HH to MI in the DATEDIFFs and remove the +1's.



For better, quicker answers on T-SQL questions, read Jeff Moden's suggestions.

"Million-to-one chances crop up nine times out of ten." ― Terry Pratchett, Mort
dwain.c
dwain.c
SSCertifiable
SSCertifiable (7.6K reputation)SSCertifiable (7.6K reputation)SSCertifiable (7.6K reputation)SSCertifiable (7.6K reputation)SSCertifiable (7.6K reputation)SSCertifiable (7.6K reputation)SSCertifiable (7.6K reputation)SSCertifiable (7.6K reputation)

Group: General Forum Members
Points: 7623 Visits: 6431
I think I'm missing something here but for what it's worth:


WITH SampleData (start_time, end_time) AS (
SELECT '22:00', '05:59'
UNION ALL SELECT '12:00', '18:59'
)
SELECT start_time, end_time
,ElapsedMin=
CASE WHEN st > et
THEN 1440-DATEDIFF(minute, et, st)
ELSE DATEDIFF(minute, st, et)
END
FROM SampleData a
CROSS APPLY (SELECT st=CAST(start_time AS TIME), et=CAST(end_time AS TIME)) b;




Note: The CROSS APPLY is not even necessary. I only included it to show explicitly the CAST that would occur implicitly anyway.


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!
My temporal SQL musings: Calendar Tables, an Easter SQL, Time Slots and Self-maintaining, Contiguous Effective Dates in Temporal Tables
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