December 11, 2007 at 1:44 am
I have a table with a big amount of data.
In my application I need to fetch data from this table entered between two dates (let's say 1 month).
There are three ways of doing this:
1. SELECT info FROM table WHERE tabledatetime >= myStartdate AND tabledatetime <= myEnddate
2. SELECT info FROM table WHERE tabledatetime BETWEEN myStartdate AND myEnddate
3. SELECT info FROM table WHERE year(tabledatetime)=myYear AND month(tabledatetime)=myMonth
1 is the slowest, that's not hard.
But what about the other 2, which one will give me the best performance.
greetz
Leon
December 11, 2007 at 2:27 am
Try a covering index on the date column and the info column your are looking for. In other words a non cluster non unique index on the two columns and switch displaying of the querying plan on when executing your query. Alternatively a partitioned view/table can help.
December 11, 2007 at 5:08 am
Actually, 3 is the slowest once you have indexes on the table. Since you are using a function against your table column, SQL cannot use an index and it must resolve the function on every row in your table.
I would expect 1 and 2 to generate the same execution plan and perform exactly the same, but the confirm you need to examine the execution plans.
December 11, 2007 at 10:45 pm
I agree with Michael here, you definitely do not want to use option 3. Since this table is big and seems to be a heavy hitter, I would make sure you have the proper indices to create a covering index.
Options 1 and 2 should evalute the same, so I would choose option 2 because it has an easier syntax and is easier to read/type :D.
December 11, 2007 at 11:44 pm
If you have index on myStartdate then between is faster.
December 12, 2007 at 12:34 am
With an appropriate index*, the first 2 can do an index seek to get the data. The third, since it has functions applied to the columns, will do at best an index scan.
The first 2 are functionally identical and, if you check the exec plan, you'll notice that SQL converts between into the <=, >= construct.
If there are no indexes on tabledatetime, all three will likely be about the same
* Appropriate index should be a covering one, tabledatetime as the leading column and the columns in the select either as other index key columns, or as include columns
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
December 13, 2007 at 10:07 am
1) Be careful adding a bunch of columns to an index just to make it covering. There is maintenance cost and disk storage cost to this.
2) An index on the date won't be helpful if a months worth of data is more than ~8-10% of the table, unless said index is covering.
3) If your predominant access of this table is by date range, consider making the clustered index the date field used.
Best,
Kevin G. Boles
SQL Server Consultant
SQL MVP 2007-2012
TheSQLGuru on googles mail service
Viewing 7 posts - 1 through 6 (of 6 total)
You must be logged in to reply to this topic. Login to reply