September 9, 2013 at 5:35 am
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
September 9, 2013 at 7:31 am
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
Consultant - Straight Path Solutions
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
September 9, 2013 at 7:34 am
September 9, 2013 at 7:44 am
many thanks for the reply,
I have been trying for hours to understand the problem. I will try and let you know.
Thanks
September 9, 2013 at 9:13 am
It worked. Thanks guys!
September 10, 2013 at 1:15 am
Here's another method.
DECLARE @StartVarchar(5) = '07:00',
@EndVarchar(5) = '05:59'
SELECTCASE
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.
September 10, 2013 at 6:34 pm
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 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
Viewing 7 posts - 1 through 6 (of 6 total)
You must be logged in to reply to this topic. Login to reply