September 26, 2013 at 1:01 pm
CREATE TABLE [dbo].[Schedule](
[id] [int] IDENTITY(1,1) NOT NULL,
[weekdayid] [int] NULL,
[starttime] [varchar](10) NULL,
[endtime] [varchar](10) NULL
)
GO
INSERT INTO [dbo].[Schedule]
VALUES(1,'9:00am','10:00am')
INSERT INTO [dbo].[Schedule]
VALUES(1,'11:00am','12:00pm')
INSERT INTO [dbo].[Schedule]
VALUES(1,'2:00pm','4:00pm')
INSERT INTO [dbo].[Schedule]
VALUES(1,'6:00pm','8:00pm')
id weekdayid starttime endtime
----------- ----------- ---------- ----------
1 1 9:00am 10:00am
2 1 11:00am 12:00pm
3 1 2:00pm 4:00pm
4 1 6:00pm 8:00pm
How to validate parameters passed as @startime.@endtime from SP should not fall outside the timeframe for the same day.
September 26, 2013 at 1:47 pm
Can you explain your problem? I don't understand how do you define your business rules.
Why are you using char(10) instead of a proper data type for time?
September 26, 2013 at 2:09 pm
Luis is absolutely correct about datatypes here. You are using sql 2008 so you have the time datatype. This would be the appropriate time (pun intended) to use that datatype.
CREATE TABLE [dbo].[Schedule]
(
[id] [int] IDENTITY(1,1) NOT NULL,
[weekdayid] [int] NULL,
[starttime] time NULL,
[endtime] time NULL
)
Now that you have a datatype you can do some calculations with this becomes simple.
declare @ParameterWithCorrectDatatype time = '10:00am'
if exists(select * from Schedule where @ParameterWithCorrectDatatype >= starttime and @ParameterWithCorrectDatatype <= endtime)
select 'The parameter is valid.'
else
select 'The parameter is invalid.'
I say the incorrect data type here because I would make the parameter's datatype also be time.
You can kludge the same thing using varchar however there are a couple of issues with that.
1) It will not perform as well because of all the datatype conversion required.
2) If you have ANY row in the table that is not able to be cast as time it will fail.
Here is what the same code would look using varchar instead of time.
declare @ParameterWithIncorrectDatatype varchar(10) = '10:00am'
if exists(select * from Schedule where cast(@ParameterWithIncorrectDatatype as time) >= cast(starttime as time) and cast(@ParameterWithIncorrectDatatype as time) <= cast(endtime as time))
select 'The parameter is valid.'
else
select 'The parameter is invalid.'
Hope that helps.
_______________________________________________________________
Need help? Help us help you.
Read the article at http://www.sqlservercentral.com/articles/Best+Practices/61537/ for best practices on asking questions.
Need to split a string? Try Jeff Modens splitter http://www.sqlservercentral.com/articles/Tally+Table/72993/.
Cross Tabs and Pivots, Part 1 – Converting Rows to Columns - http://www.sqlservercentral.com/articles/T-SQL/63681/
Cross Tabs and Pivots, Part 2 - Dynamic Cross Tabs - http://www.sqlservercentral.com/articles/Crosstab/65048/
Understanding and Using APPLY (Part 1) - http://www.sqlservercentral.com/articles/APPLY/69953/
Understanding and Using APPLY (Part 2) - http://www.sqlservercentral.com/articles/APPLY/69954/
September 26, 2013 at 7:19 pm
Personally, if I couldn't correct it on data capture and in the table definition, I'd probably convert it to a TIME data type and do my validation from there.
SELECT *
,st=CAST(
DATEADD(hour,
CASE RIGHT(starttime, 2)
WHEN 'am' THEN 0
ELSE 12
END
,LEFT(starttime, PATINDEX('%[amp]%', starttime)-1)) AS TIME)
,et=CAST(DATEADD(hour,
CASE RIGHT(endtime, 2)
WHEN 'am' THEN 0
ELSE 12
END
,LEFT(endtime, PATINDEX('%[amp]%', endtime)-1)) AS TIME)
FROM #Schedule;
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
September 27, 2013 at 9:50 am
Btw, if weekdayid is unique (and it seems like it has to be for this table to make sense), get rid of the dopey IDENTITY column in this table! Cluster the table by weekdayid instead.
SQL DBA,SQL Server MVP(07, 08, 09) "It's a dog-eat-dog world, and I'm wearing Milk-Bone underwear." "Norm", on "Cheers". Also from "Cheers", from "Carla": "You need to know 3 things about Tortelli men: Tortelli men draw women like flies; Tortelli men treat women like flies; Tortelli men's brains are in their flies".
Viewing 5 posts - 1 through 4 (of 4 total)
You must be logged in to reply to this topic. Login to reply