What about MONTH and YEAR functions?

  • 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

  • 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)

  • 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.

  • 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))

    😎

  • 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.

  • 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". 😉 Do they work? Yes, today they do... when 2008 comes out, it will "depend". 😉

    --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.

    Change is inevitable... Change for the better is not.


    Helpful Links:
    How to post code problems
    How to Post Performance Problems
    Create a Tally Function (fnTally)

Viewing 6 posts - 1 through 5 (of 5 total)

You must be logged in to reply to this topic. Login to reply