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

Newbie needs help with a query!! Expand / Collapse
Author
Message
Posted Thursday, September 26, 2013 1:01 PM
Forum Newbie

Forum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum Newbie

Group: General Forum Members
Last Login: Monday, June 9, 2014 1:20 PM
Points: 9, Visits: 84
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.
Post #1499025
Posted Thursday, September 26, 2013 1:47 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: Yesterday @ 7:02 PM
Points: 3,313, Visits: 7,151
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.
I am a great believer in luck, and I find the harder I work the more I have of it. Stephen Leacock

Forum Etiquette: How to post data/code on a forum to get the best help
Post #1499047
Posted Thursday, September 26, 2013 2:09 PM


SSChampion

SSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampion

Group: General Forum Members
Last Login: Yesterday @ 2:50 PM
Points: 13,062, Visits: 11,891
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)
Post #1499055
Posted Thursday, September 26, 2013 7:19 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: Yesterday @ 6:12 PM
Points: 3,609, Visits: 5,220
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!
Post #1499136
Posted Friday, September 27, 2013 9:50 AM
SSCommitted

SSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommitted

Group: General Forum Members
Last Login: Yesterday @ 2:07 PM
Points: 1,949, Visits: 2,884
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)
"In America, every man is innocent until proven broke!" Brant Parker
Post #1499483
« Prev Topic | Next Topic »

Add to briefcase

Permissions Expand / Collapse