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

select data between 2 periods Expand / Collapse
Author
Message
Posted Tuesday, December 11, 2007 1:44 AM
Forum Newbie

Forum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum Newbie

Group: General Forum Members
Last Login: Wednesday, August 31, 2011 7:53 AM
Points: 7, Visits: 47
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
Post #431662
Posted Tuesday, December 11, 2007 2:27 AM
Valued Member

Valued MemberValued MemberValued MemberValued MemberValued MemberValued MemberValued MemberValued Member

Group: General Forum Members
Last Login: Friday, June 20, 2014 4:05 AM
Points: 72, Visits: 463
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.


Post #431671
Posted Tuesday, December 11, 2007 5:08 AM
SSCrazy

SSCrazySSCrazySSCrazySSCrazySSCrazySSCrazySSCrazySSCrazy

Group: General Forum Members
Last Login: Tuesday, August 10, 2010 5:07 AM
Points: 2,732, Visits: 23,078
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.

Post #431705
Posted Tuesday, December 11, 2007 10:45 PM
SSCrazy

SSCrazySSCrazySSCrazySSCrazySSCrazySSCrazySSCrazySSCrazy

Group: General Forum Members
Last Login: Wednesday, August 20, 2014 10:35 AM
Points: 2,278, Visits: 3,056
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.




My blog: http://jahaines.blogspot.com
Post #432140
Posted Tuesday, December 11, 2007 11:44 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: Tuesday, August 5, 2014 8:57 AM
Points: 3,167, Visits: 1,060
If you have index on myStartdate then between is faster.


Post #432145
Posted Wednesday, December 12, 2007 12:34 AM


SSC-Forever

SSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-Forever

Group: General Forum Members
Last Login: Today @ 3:52 PM
Points: 42,849, Visits: 35,978
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 2008, MVP
SQL In The Wild: Discussions on DB performance with occasional diversions into recoverability

We walk in the dark places no others will enter
We stand on the bridge and no one may pass

Post #432157
Posted Thursday, December 13, 2007 10:07 AM


SSCarpal Tunnel

SSCarpal TunnelSSCarpal TunnelSSCarpal TunnelSSCarpal TunnelSSCarpal TunnelSSCarpal TunnelSSCarpal TunnelSSCarpal TunnelSSCarpal Tunnel

Group: General Forum Members
Last Login: Today @ 8:23 AM
Points: 4,352, Visits: 6,168
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 at GMail
Post #432957
« Prev Topic | Next Topic »

Add to briefcase

Permissions Expand / Collapse