Click here to monitor SSC
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


Newbie needs help with a query!!


Newbie needs help with a query!!

Author
Message
ks2007
ks2007
Grasshopper
Grasshopper (10 reputation)Grasshopper (10 reputation)Grasshopper (10 reputation)Grasshopper (10 reputation)Grasshopper (10 reputation)Grasshopper (10 reputation)Grasshopper (10 reputation)Grasshopper (10 reputation)

Group: General Forum Members
Points: 10 Visits: 108
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.
Luis Cazares
Luis Cazares
SSCrazy Eights
SSCrazy Eights (8.6K reputation)SSCrazy Eights (8.6K reputation)SSCrazy Eights (8.6K reputation)SSCrazy Eights (8.6K reputation)SSCrazy Eights (8.6K reputation)SSCrazy Eights (8.6K reputation)SSCrazy Eights (8.6K reputation)SSCrazy Eights (8.6K reputation)

Group: General Forum Members
Points: 8556 Visits: 18143
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?


Luis C.
General Disclaimer:
Are you seriously taking the advice and code from someone from the internet without testing it? Do you at least understand it? Or can it easily kill your server?


How to post data/code on a forum to get the best help: Option 1 / Option 2
Sean Lange
Sean Lange
SSCoach
SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)

Group: General Forum Members
Points: 16616 Visits: 17024
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 Moden's splitter.

Cross Tabs and Pivots, Part 1 – Converting Rows to Columns
Cross Tabs and Pivots, Part 2 - Dynamic Cross Tabs
Understanding and Using APPLY (Part 1)
Understanding and Using APPLY (Part 2)
dwain.c
dwain.c
SSCarpal Tunnel
SSCarpal Tunnel (4.3K reputation)SSCarpal Tunnel (4.3K reputation)SSCarpal Tunnel (4.3K reputation)SSCarpal Tunnel (4.3K reputation)SSCarpal Tunnel (4.3K reputation)SSCarpal Tunnel (4.3K reputation)SSCarpal Tunnel (4.3K reputation)SSCarpal Tunnel (4.3K reputation)

Group: General Forum Members
Points: 4259 Visits: 6431
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 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
ScottPletcher
ScottPletcher
Hall of Fame
Hall of Fame (3.9K reputation)Hall of Fame (3.9K reputation)Hall of Fame (3.9K reputation)Hall of Fame (3.9K reputation)Hall of Fame (3.9K reputation)Hall of Fame (3.9K reputation)Hall of Fame (3.9K reputation)Hall of Fame (3.9K reputation)

Group: General Forum Members
Points: 3946 Visits: 6686
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)

Prosecutor James Blackburn, in closing argument in the "Fatal Vision" murders trial: "If in the future, you should cry a tear, cry one for them [the murder victims]. If in the future, you should say a prayer, say one for them. And if in the future, you should light a candle, light one for them."
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