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

Time Range Expand / Collapse
Author
Message
Posted Monday, September 9, 2013 5:35 AM
Grasshopper

GrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopper

Group: General Forum Members
Last Login: Saturday, November 30, 2013 2:38 PM
Points: 15, Visits: 57
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
Post #1492737
Posted Monday, September 9, 2013 7:31 AM


SSChampion

SSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampion

Group: General Forum Members
Last Login: Today @ 9:42 AM
Points: 11,223, Visits: 12,983
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

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
Post #1492778
Posted Monday, September 9, 2013 7:34 AM


SSC Eights!

SSC Eights!SSC Eights!SSC Eights!SSC Eights!SSC Eights!SSC Eights!SSC Eights!SSC Eights!

Group: General Forum Members
Last Login: Today @ 7:47 AM
Points: 872, Visits: 2,784
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
Post #1492780
Posted Monday, September 9, 2013 7:44 AM
Grasshopper

GrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopper

Group: General Forum Members
Last Login: Saturday, November 30, 2013 2:38 PM
Points: 15, Visits: 57
many thanks for the reply,

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

Thanks
Post #1492786
Posted Monday, September 9, 2013 9:13 AM
Grasshopper

GrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopper

Group: General Forum Members
Last Login: Saturday, November 30, 2013 2:38 PM
Points: 15, Visits: 57
It worked. Thanks guys!

Post #1492824
Posted Tuesday, September 10, 2013 1:15 AM
SSC-Enthusiastic

SSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-Enthusiastic

Group: General Forum Members
Last Login: Thursday, March 6, 2014 1:35 AM
Points: 178, 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
Post #1493015
Posted Tuesday, September 10, 2013 6:34 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: 2 days ago @ 4:14 AM
Points: 3,618, Visits: 5,254
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!
Post #1493407
« Prev Topic | Next Topic »

Add to briefcase

Permissions Expand / Collapse