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


Problem with Datetime Function


Problem with Datetime Function

Author
Message
mahesh.dasoni
mahesh.dasoni
SSC-Enthusiastic
SSC-Enthusiastic (159 reputation)SSC-Enthusiastic (159 reputation)SSC-Enthusiastic (159 reputation)SSC-Enthusiastic (159 reputation)SSC-Enthusiastic (159 reputation)SSC-Enthusiastic (159 reputation)SSC-Enthusiastic (159 reputation)SSC-Enthusiastic (159 reputation)

Group: General Forum Members
Points: 159 Visits: 1025
I have SP which contains function
convert(varchar(12),[datetime],112) =convert(varchar(12),getdate(),112)
this takes lots of time during the Market hours and it is very essential as well.
Is there any alternate which we can use for this function
Dave Ballantyne
Dave Ballantyne
Hall of Fame
Hall of Fame (3.8K reputation)Hall of Fame (3.8K reputation)Hall of Fame (3.8K reputation)Hall of Fame (3.8K reputation)Hall of Fame (3.8K reputation)Hall of Fame (3.8K reputation)Hall of Fame (3.8K reputation)Hall of Fame (3.8K reputation)

Group: General Forum Members
Points: 3810 Visits: 8370
So this is in a WHERE clause ??

Assuming so, this is what is known as a non-sargable condition.
Basically, as you have wrapped the datetime column in a function then SQL Server has to look at and process every row rather than use the more optimal route of an index.

Definition :
http://en.wikipedia.org/wiki/Sargable

One of the many blog articles available:
http://beyondrelational.com/modules/2/blogs/66/posts/9925/sargable-predicates.aspx



Clear Sky SQL
My Blog
mahesh.dasoni
mahesh.dasoni
SSC-Enthusiastic
SSC-Enthusiastic (159 reputation)SSC-Enthusiastic (159 reputation)SSC-Enthusiastic (159 reputation)SSC-Enthusiastic (159 reputation)SSC-Enthusiastic (159 reputation)SSC-Enthusiastic (159 reputation)SSC-Enthusiastic (159 reputation)SSC-Enthusiastic (159 reputation)

Group: General Forum Members
Points: 159 Visits: 1025
Yes it is being used in the where clause so what can be used instead of this fuction which will take less time
Dave Ballantyne
Dave Ballantyne
Hall of Fame
Hall of Fame (3.8K reputation)Hall of Fame (3.8K reputation)Hall of Fame (3.8K reputation)Hall of Fame (3.8K reputation)Hall of Fame (3.8K reputation)Hall of Fame (3.8K reputation)Hall of Fame (3.8K reputation)Hall of Fame (3.8K reputation)

Group: General Forum Members
Points: 3810 Visits: 8370
Did you read those articles ?

Example 3 on the beyondrelational one is very close to what you require.



Clear Sky SQL
My Blog
Lynn Pettis
Lynn Pettis
SSC Guru
SSC Guru (51K reputation)SSC Guru (51K reputation)SSC Guru (51K reputation)SSC Guru (51K reputation)SSC Guru (51K reputation)SSC Guru (51K reputation)SSC Guru (51K reputation)SSC Guru (51K reputation)

Group: General Forum Members
Points: 51816 Visits: 38684
mahesh.dasoni (12/16/2012)
I have SP which contains function
convert(varchar(12),[datetime],112) =convert(varchar(12),getdate(),112)
this takes lots of time during the Market hours and it is very essential as well.
Is there any alternate which we can use for this function


Try this in your where clause:



([datetime] >= dateadd(dd, datediff(dd, 0, getdate()), 0) and
[datetime] < dateadd(dd, datediff(dd, 0, getdate()) + 1, 0))




Also, please note that your column name datetime is a very poor choice as it is also a reserved word.

The reason your current criteria is taking a long time to process is that SQL Server has to apply the convert function to every value of datetime in your table.

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)
Andre Ranieri
Andre Ranieri
SSChasing Mays
SSChasing Mays (637 reputation)SSChasing Mays (637 reputation)SSChasing Mays (637 reputation)SSChasing Mays (637 reputation)SSChasing Mays (637 reputation)SSChasing Mays (637 reputation)SSChasing Mays (637 reputation)SSChasing Mays (637 reputation)

Group: General Forum Members
Points: 637 Visits: 379
if the left side of the equal sign is a calculation, then the WHERE clause is "non sargeable", meaning that the optimizer can't use simple search arguments and must instead build an efficient query plan and must calculate every field in your table in this matter.

Maybe something like

-- midnight today
DECLARE @dFrom datetime = dateadd(dd, datediff(dd, 0, getdate()), 0)

-- 23:59:59 today
DECLARE @dTo datetime = DATEADD(dd, 1, @dFrom)

Then, in your WHERE clause:

[datetime] >= @dFrom AND [datetime] < @dTo

See if you get a better execution plan with this.
Adi Cohn
Adi Cohn
SSCarpal Tunnel
SSCarpal Tunnel (4.5K reputation)SSCarpal Tunnel (4.5K reputation)SSCarpal Tunnel (4.5K reputation)SSCarpal Tunnel (4.5K reputation)SSCarpal Tunnel (4.5K reputation)SSCarpal Tunnel (4.5K reputation)SSCarpal Tunnel (4.5K reputation)SSCarpal Tunnel (4.5K reputation)

Group: General Forum Members
Points: 4517 Visits: 6515
Andre Ranieri (12/17/2012)
if the left side of the equal sign is a calculation, then the WHERE clause is "non sargeable", meaning that the optimizer can't use simple search arguments and must instead build an efficient query plan and must calculate every field in your table in this matter.

Maybe something like

-- midnight today
DECLARE @dFrom datetime = dateadd(dd, datediff(dd, 0, getdate()), 0)

-- 23:59:59 today
DECLARE @dTo datetime = DATEADD(dd, 1, @dFrom)

Then, in your WHERE clause:

[datetime] >= @dFrom AND [datetime] < @dTo

See if you get a better execution plan with this.


There is a very good chance that this will cause a table scan. A query plan is created only for data access statements (e.g. select, insert, update, delete, etc'). It completely ignores a variables assignment which is done in memory. In your example, the server will create a query plan without knowing the values of @dFrom and @dTo, so it will guess that 20% of the table's records will be selected. In the vast majority of times this will cause a table scan. It can work if you'll have the select statement in a different procedure and you'll send the values of @dFrom and @dTo as parameters to the procedure. This is because in the case of procedures and parameters, the server works with parameter sniffing.

Adi

--------------------------------------------------------------
To know how to ask questions and increase the chances of getting asnwers:
http://www.sqlservercentral.com/articles/Best+Practices/61537/

For better answers on performance questions, click on the following...
http://www.sqlservercentral.com/articles/SQLServerCentral/66909/
GSquared
GSquared
SSC-Dedicated
SSC-Dedicated (30K reputation)SSC-Dedicated (30K reputation)SSC-Dedicated (30K reputation)SSC-Dedicated (30K reputation)SSC-Dedicated (30K reputation)SSC-Dedicated (30K reputation)SSC-Dedicated (30K reputation)SSC-Dedicated (30K reputation)

Group: General Forum Members
Points: 30771 Visits: 9730
Something that many don't know about SARGability is that some functions, regardless of side of equation in a Where clause, are SARGable.

Try this:

SET NOCOUNT ON;
USE ProofOfConcept;
GO
CREATE TABLE dbo.SARGTest (
DT DATETIME NOT NULL);
GO
CREATE CLUSTERED INDEX CID_SARGTest_DT ON dbo.SARGTest(DT);
GO
INSERT INTO dbo.SARGTest(DT)
SELECT TOP (1000000) DATEADD(DAY, CHECKSUM(NEWID())%10000, GETDATE())
FROM ProofOfConcept.dbo.Numbers AS N1
CROSS JOIN ProofOfConcept.dbo.Numbers AS N2;
GO
SELECT *
FROM dbo.SARGTest
WHERE DT >= DATEADD(DAY, DATEDIFF(DAY, 0, GETDATE()), 0)
AND DT < DATEADD(DAY, DATEDIFF(DAY, 0, GETDATE()), 1);

SELECT *
FROM dbo.SARGTest
WHERE CAST(DT AS DATE) = CAST(GETDATE() AS DATE);



Check the execution plans on both of the final queries. We know the first query will result in an index seek. It follows the usual rules for SARGability. What's surprising to many is that the second one, with CAST() on the left (and right) of the Where clause, also results in an index seek.

(Actual execution plans attached.)

Also tested:

DECLARE @S DATE = GETDATE(), @E DATE = DATEADD(DAY, 1, GETDATE());

SELECT *
FROM dbo.SARGTest
WHERE DT >= @S AND DT < @E;



Still get a seek. (See Plan2.sqlplan, attached.)

- Gus "GSquared", RSVP, OODA, MAP, NMVP, FAQ, SAT, SQL, DNA, RNA, UOI, IOU, AM, PM, AD, BC, BCE, USA, UN, CF, ROFL, LOL, ETC
Property of The Thread

"Nobody knows the age of the human race, but everyone agrees it's old enough to know better." - Anon
Attachments
Plans.sqlplan (10 views, 16.00 KB)
Plan2.sqlplan (10 views, 13.00 KB)
Sean Lange
Sean Lange
SSC-Dedicated
SSC-Dedicated (33K reputation)SSC-Dedicated (33K reputation)SSC-Dedicated (33K reputation)SSC-Dedicated (33K reputation)SSC-Dedicated (33K reputation)SSC-Dedicated (33K reputation)SSC-Dedicated (33K reputation)SSC-Dedicated (33K reputation)

Group: General Forum Members
Points: 33681 Visits: 17681
Andre Ranieri (12/17/2012)
if the left side of the equal sign is a calculation, then the WHERE clause is "non sargeable", meaning that the optimizer can't use simple search arguments and must instead build an efficient query plan and must calculate every field in your table in this matter.



That just simply isn't true. The sql engine does not care at all which side of the equal sign a given predicate is located. If it were that simple to make it sargable you could switch the order of the equals predicate. I know that even the wiki article mentions the left side of the equation but consider this from the wiki example.


Non-Sargable: Select ... WHERE Year(date) = 2012



If it were try that to make it sargable the function can't be on the left side then that is like saying that the following is sargable


WHERE 2012 = Year(date)



The above is no more sargable than the first but the left side of the equation is a constant and not a function.

_______________________________________________________________

Need help? Help us help you.

Read the article at http://www.sqlservercentral.com/articles/Best+Practices/61537/ for best practices on asking questions.

Need to split a string? Try Jeff Modens splitter.

Cross Tabs and Pivots, Part 1 – Converting Rows to Columns
Cross Tabs and Pivots, Part 2 - Dynamic Cross Tabs
Understanding and Using APPLY (Part 1)
Understanding and Using APPLY (Part 2)
Adi Cohn
Adi Cohn
SSCarpal Tunnel
SSCarpal Tunnel (4.5K reputation)SSCarpal Tunnel (4.5K reputation)SSCarpal Tunnel (4.5K reputation)SSCarpal Tunnel (4.5K reputation)SSCarpal Tunnel (4.5K reputation)SSCarpal Tunnel (4.5K reputation)SSCarpal Tunnel (4.5K reputation)SSCarpal Tunnel (4.5K reputation)

Group: General Forum Members
Points: 4517 Visits: 6515
GSquared (12/17/2012)
Something that many don't know about SARGability is that some functions, regardless of side of equation in a Where clause, are SARGable.

Try this:

SET NOCOUNT ON;
USE ProofOfConcept;
GO
CREATE TABLE dbo.SARGTest (
DT DATETIME NOT NULL);
GO
CREATE CLUSTERED INDEX CID_SARGTest_DT ON dbo.SARGTest(DT);
GO
INSERT INTO dbo.SARGTest(DT)
SELECT TOP (1000000) DATEADD(DAY, CHECKSUM(NEWID())%10000, GETDATE())
FROM ProofOfConcept.dbo.Numbers AS N1
CROSS JOIN ProofOfConcept.dbo.Numbers AS N2;
GO

Also tested:

[code="sql"]DECLARE @S DATE = GETDATE(), @E DATE = DATEADD(DAY, 1, GETDATE());

SELECT *
FROM dbo.SARGTest
WHERE DT >= @S AND DT < @E;



Still get a seek. (See Plan2.sqlplan, attached.)


I guess that the quoted part was written because of my previous message about the fact that using variables, assign them values and then use them in the same scope in the where clause will cause the server to do a table scan instead of seek operation. If I'm correct, then let be clearer about it. If you use a clustered index, then seek operation will be used. If you'll use an appropriate none clustered index that is also a covering index to this query, then you'll get seek operation. If you'll use none clustered index that is not covering, then most times you will get scan operation. In your example you had a table with one column and a clustered that is based on this column. Here is an example that is based on the code that you've added to your message:



CREATE TABLE dbo.SARGTest (
DT DATETIME NOT NULL, filler char(1) default ('a'));
GO

INSERT INTO dbo.SARGTest(DT)
SELECT TOP (1000000) DATEADD(DAY, CHECKSUM(NEWID())%10000, GETDATE())
FROM sys.objects
CROSS JOIN sys.objects as s2

CREATE INDEX CID_SARGTest_DT ON dbo.SARGTest(DT);


DECLARE @S datetime
declare @E datetime

SET @S = GETDATE()
SET @E = DATEADD(DAY, 1, GETDATE())

--Using the varibles cause table scan
SELECT *
FROM dbo.SARGTest
WHERE DT >= @S AND DT < @E;

--Using the same values but without the varibles use a table seek
SELECT *
FROM dbo.SARGTest
where DT > GETDATE() AND DT < DATEADD(DAY, 1, GETDATE())
go

drop table SARGTest



--------------------------------------------------------------
To know how to ask questions and increase the chances of getting asnwers:
http://www.sqlservercentral.com/articles/Best+Practices/61537/

For better answers on performance questions, click on the following...
http://www.sqlservercentral.com/articles/SQLServerCentral/66909/
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