July 3, 2014 at 5:12 am
Getting a bit frustrated over this simple select statement.
I'd like to select all entries (including full date) where the year part of the date column is say '2014'
SELECT
dbclaimcnt, dbclaimentered
FROM
EPSClaimsUOA
WHERE
dbclaimentered = '2014'
thanks
July 3, 2014 at 5:25 am
there is a YEAR function that returns an integer, that can do what you are asking:
there is also a DATEPART function that can do the same, but you can pull out pieces like the integer representing a day, month week,year or other things if the need arose (quarters?):
SELECT
dbclaimcnt, dbclaimentered
FROM
EPSClaimsUOA
WHERE
YEAR(dbclaimentered) = 2014
SELECT
dbclaimcnt, dbclaimentered
FROM
EPSClaimsUOA
WHERE
select DATEPART(yy,dbclaimentered) = 2014
Lowell
July 3, 2014 at 5:31 am
thanks, they both do the job (minus the select in the second where sql statement)
July 3, 2014 at 6:00 am
Do note that using functions on the columns like that prevents any index seek for that predicate.
If that column is a date, then:
SELECT
dbclaimcnt, dbclaimentered
FROM
EPSClaimsUOA
WHERE
dbclaimentered >= '2014-01-01' and dbclaimentered < '2015-01-01'
Gail Shaw
Microsoft Certified Master: SQL Server, MVP, M.Sc (Comp Sci)
SQL In The Wild: Discussions on DB performance with occasional diversions into recoverability
July 3, 2014 at 8:16 am
Another often used solution to something like this is to have a calendar table with a schema similar to this:
CREATE TABLE dbo.calendar
(
theDate DATETIME,
theYear INT,
theQuarter TINYINT,
theMonth TINYINT,
weekOfYear TINYINT
theDayOfYear TINYINT
)
Then you do a query like this:
SELECT
dbclaimcnt,
dbclaimentered
FROM
EPSClaimsUOA
WHERE
EXISTS ( SELECT
1
FROM
dbo.calendar
WHERE
theYear = 2014 AND
dbclaimentered >= theDate AND
dbclaimentered <= theDate )
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
July 3, 2014 at 8:25 am
GilaMonster (7/3/2014)
Do note that using functions on the columns like that prevents any index seek for that predicate.If that column is a date, then:
SELECT
dbclaimcnt, dbclaimentered
FROM
EPSClaimsUOA
WHERE
dbclaimentered >= '2014-01-01' and dbclaimentered < '2015-01-01'
Good example of why letting the OP select "Mark as Solution" is not a good idea.
July 3, 2014 at 8:38 am
Michael Valentine Jones (7/3/2014)
GilaMonster (7/3/2014)
Do note that using functions on the columns like that prevents any index seek for that predicate.If that column is a date, then:
SELECT
dbclaimcnt, dbclaimentered
FROM
EPSClaimsUOA
WHERE
dbclaimentered >= '2014-01-01' and dbclaimentered < '2015-01-01'
Good example of why letting the OP select "Mark as Solution" is not a good idea.
Technically that is a valid solution, just not necessarily the best performing solution. At least marking an answer as a solution doesn't close the thread.
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
July 3, 2014 at 8:48 am
Michael Valentine Jones (7/3/2014)
GilaMonster (7/3/2014)
Do note that using functions on the columns like that prevents any index seek for that predicate.If that column is a date, then:
SELECT
dbclaimcnt, dbclaimentered
FROM
EPSClaimsUOA
WHERE
dbclaimentered >= '2014-01-01' and dbclaimentered < '2015-01-01'
Good example of why letting the OP select "Mark as Solution" is not a good idea.
It was marked as the solution long before I posted that, and the OP hasn't logged in since.
Gail Shaw
Microsoft Certified Master: SQL Server, MVP, M.Sc (Comp Sci)
SQL In The Wild: Discussions on DB performance with occasional diversions into recoverability
July 4, 2014 at 2:17 am
Thanks Gila and Jack point taken on index consideration.
'2014' was an example, that value's passed by the user.
Jones post - a good example of reading the posts fully before posting opinions perhaps.
July 4, 2014 at 2:27 am
mattech06 (7/4/2014)
'2014' was an example, that value's passed by the user.
You can still use either Jack's or my solutions with a value passed from a user. You'd just need a local variable to use to build up a date
Gail Shaw
Microsoft Certified Master: SQL Server, MVP, M.Sc (Comp Sci)
SQL In The Wild: Discussions on DB performance with occasional diversions into recoverability
July 4, 2014 at 2:43 am
yep, thanks Gila
Viewing 11 posts - 1 through 10 (of 10 total)
You must be logged in to reply to this topic. Login to reply