SQL Clone
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


What about MONTH and YEAR functions?


What about MONTH and YEAR functions?

Author
Message
ruben ruvalcaba
ruben ruvalcaba
Grasshopper
Grasshopper (15 reputation)Grasshopper (15 reputation)Grasshopper (15 reputation)Grasshopper (15 reputation)Grasshopper (15 reputation)Grasshopper (15 reputation)Grasshopper (15 reputation)Grasshopper (15 reputation)

Group: General Forum Members
Points: 15 Visits: 104
Hi,

First of all thank you, it's a good point to be considered. In fact, I use functions on the WHERE clause very often, specially when filtering dates ... how do you optimize a query like this:

SELECT SUM(Amount) FROM myEntries WHERE YEAR(myEntries.myDate) = @Year AND MONTH(myEntries.myDate) <= @Month

Any clue? thank you

regards
Michael Valentine Jones
Michael Valentine Jones
SSChampion
SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)

Group: General Forum Members
Points: 14199 Visits: 11848
Do queries like this as a selection against a range in this form:
where date >= @StartOfRange and date < @EndOf Range

In the following code, it will be the same as this:
where date >= '2008-01-01' and date < '2008-03-01'

declare @year int
declare @month int

select @year = 2008, @month = 2

select
*
from
MyTable
where
-- Date on or after start of year
MyTable.MyDate >= dateadd(month,(12*@Year)-22801+1,0) and
-- Date before start of next month
MyTable.MyDate < dateadd(month,(12*@Year)-22801+@Month+1,0)





Jack Corbett
  Jack Corbett
SSC-Forever
SSC-Forever (43K reputation)SSC-Forever (43K reputation)SSC-Forever (43K reputation)SSC-Forever (43K reputation)SSC-Forever (43K reputation)SSC-Forever (43K reputation)SSC-Forever (43K reputation)SSC-Forever (43K reputation)

Group: General Forum Members
Points: 43765 Visits: 14925
If this is how you will most often be querying your data you should have month and year columns in table with an index. Or, write your queries with explicit date ranges. If you want your users to be able to enter month and year paramters then convert them to dates after entry. So year=2008 and month=3 would become. Startdate=1/1/2008 & endate=3/31/2008.



Jack Corbett

Applications Developer

Don't let the good be the enemy of the best. -- Paul Fleming
At best you can say that one job may be more secure than another, but total job security is an illusion. -- Rod at work

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
Lynn Pettis
Lynn Pettis
SSC Guru
SSC Guru (93K reputation)SSC Guru (93K reputation)SSC Guru (93K reputation)SSC Guru (93K reputation)SSC Guru (93K reputation)SSC Guru (93K reputation)SSC Guru (93K reputation)SSC Guru (93K reputation)

Group: General Forum Members
Points: 93233 Visits: 38955
here is a slight variation to what Michael Valentine Jones provided:



declare @year smallint,
@month tinyint

set @year = 2007
set @month = 2

select
sum(Amount)
from
dbo.myEntries
where
myEntries.myDate >= dateadd(yy,(@year - 1900), 0)
and myEntries.myDate < dateadd(mm, @month, dateadd(yy,(@year - 1900), 0))




Cool

Cool
Lynn Pettis

For better assistance in answering your questions, click here
For tips to get better help with Performance Problems, click here
For Running Totals and its variations, click here or when working with partitioned tables
For more about Tally Tables, click here
For more about Cross Tabs and Pivots, click here and here
Managing Transaction Logs

SQL Musings from the Desert Fountain Valley SQL (My Mirror Blog)
Jack Corbett
  Jack Corbett
SSC-Forever
SSC-Forever (43K reputation)SSC-Forever (43K reputation)SSC-Forever (43K reputation)SSC-Forever (43K reputation)SSC-Forever (43K reputation)SSC-Forever (43K reputation)SSC-Forever (43K reputation)SSC-Forever (43K reputation)

Group: General Forum Members
Points: 43765 Visits: 14925
The thing about functions in where clauses is that, if on a column, you have to run every row through the function while using them on a parameter or constant the optimizer can run it once. This is why Michael's and Lynn's solutions are more effecient.



Jack Corbett

Applications Developer

Don't let the good be the enemy of the best. -- Paul Fleming
At best you can say that one job may be more secure than another, but total job security is an illusion. -- Rod at work

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
Jeff Moden
Jeff Moden
SSC Guru
SSC Guru (211K reputation)SSC Guru (211K reputation)SSC Guru (211K reputation)SSC Guru (211K reputation)SSC Guru (211K reputation)SSC Guru (211K reputation)SSC Guru (211K reputation)SSC Guru (211K reputation)

Group: General Forum Members
Points: 211205 Visits: 41977
For too many reasons to list in this short amount of space, I strongly recommend that you never process dates by individual Year and/or Month components. Some of the others have already suggested how to handle things... always treat dates as a range... yep... even if the date is for one measely day. WHERE clauses should always follow the general format of...

  WHERE somedatecol >= @StartDate
AND somedatecol < @EndDate+1



That is assuming, of course, that you are working with whole dates that either have no literally expressed time component (defaults to midnight) or has a time component of precisely 00:00:00.000. Other considerations will need be made if @StartDate or @EndDate have a non-midnight time component. Doesn't matter if "somedatecol" does or not and that's the beauty of the method shown above. And, it'll allow for very high performance Index SEEKs if the correct indexes are available.

You will also find those that suggest that you use one of the following...

  WHERE somedatecol BETWEEN @StartDate AND DATEADD(ms,-3,@EndDate+1)
WHERE somedatecol BETWEEN @StartDate AND @EndDate+'23:59:59.997



Treat them just like street drugs... just say "NO". Wink Do they work? Yes, today they do... when 2008 comes out, it will "depend". Wink

--Jeff Moden

RBAR is pronounced ree-bar and is a Modenism for Row-By-Agonizing-Row.
First step towards the paradigm shift of writing Set Based code:
Stop thinking about what you want to do to a row... think, instead, of what you want to do to a column.
If you think its expensive to hire a professional to do the job, wait until you hire an amateur. -- Red Adair

Helpful Links:
How to post code problems
How to post performance problems
Forum FAQs
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