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


Get date not working


Get date not working

Author
Message
dbman
dbman
SSCommitted
SSCommitted (1.8K reputation)SSCommitted (1.8K reputation)SSCommitted (1.8K reputation)SSCommitted (1.8K reputation)SSCommitted (1.8K reputation)SSCommitted (1.8K reputation)SSCommitted (1.8K reputation)SSCommitted (1.8K reputation)

Group: General Forum Members
Points: 1803 Visits: 1537
Hello,

I am trying to create a query to get the results for yesterdays data only. So basically i need all the sales for yesterdays invoices date. I am running the query and getting zero results. The SQL i am using is below. Does anyone know if i am doing this wrong?

SELECT [Invoice_Date]
,[UserId]
,[Customer]
,[InvoiceNo]
,[Description]
,[Pack]
,[PIP_Code]
,[Class]
,[Major_Grp]
,[Invoice_Val]
,[Cost_Pr]
,[Quantity]
FROM [Telesales].[dbo].[Sales]
Where DATEADD(d,-1,GETDATE()) = Invoice_Date


Also tried:


SELECT [Invoice_Date]
,[UserId]
,[Customer]
,[InvoiceNo]
,[Description]
,[Pack]
,[PIP_Code]
,[Class]
,[Major_Grp]
,[Invoice_Val]
,[Cost_Pr]
,[Quantity]
FROM [Telesales].[dbo].[Sales]
Where Invoice_Date = (GETDATE() - 1)
alpeshchauhan
alpeshchauhan
SSC Rookie
SSC Rookie (41 reputation)SSC Rookie (41 reputation)SSC Rookie (41 reputation)SSC Rookie (41 reputation)SSC Rookie (41 reputation)SSC Rookie (41 reputation)SSC Rookie (41 reputation)SSC Rookie (41 reputation)

Group: General Forum Members
Points: 41 Visits: 27
it's not work properly............
anthony.green
anthony.green
SSC Guru
SSC Guru (62K reputation)SSC Guru (62K reputation)SSC Guru (62K reputation)SSC Guru (62K reputation)SSC Guru (62K reputation)SSC Guru (62K reputation)SSC Guru (62K reputation)SSC Guru (62K reputation)

Group: General Forum Members
Points: 62786 Visits: 8598
Thats becuase you probably wont have anything that is equal to the date being used in the where clause

You really need to do an >= < where clause

SELECT [Invoice_Date]
,[UserId]
,[Customer]
,[InvoiceNo]
,[Description]
,[Pack]
,[PIP_Code]
,[Class]
,[Major_Grp]
,[Invoice_Val]
,[Cost_Pr]
,[Quantity]
FROM [Telesales].[dbo].[Sales]
Where Invoice_Date >= dateadd(dd, datediff(dd, 0, GETDATE()) - 1, 0)
AND Invoice_Date < dateadd(dd, datediff(dd, 0, GETDATE()), 0)

Remember that dates are forever moving values

No two runs of the query are the same when using = and getdate() as the time stamp will change on each run.



How to post data/code for the best help - Jeff Moden
Need a string splitter, try this - Jeff Moden
How to post performance problems - Gail Shaw
Managing Transaction Logs - Gail Shaw
Troubleshooting SQL Server: A Guide for the Accidental DBA - Jonathan Kehayias and Ted Krueger


Ed Wagner
Ed Wagner
SSC Guru
SSC Guru (157K reputation)SSC Guru (157K reputation)SSC Guru (157K reputation)SSC Guru (157K reputation)SSC Guru (157K reputation)SSC Guru (157K reputation)SSC Guru (157K reputation)SSC Guru (157K reputation)

Group: General Forum Members
Points: 157156 Visits: 11658
If your field is a datetime data type, then you're comparing the datetime result of GetDate() against the datetime value of the field. So, nothing's going to match. I like the BETWEEN or <= and >= approach as well. That was you can avoid putting date parsing functions on the field (i.e.: to the left of the = sign) which would be a disaster for performance.

Effectively, you want use date functions that evaluate to something like this:


WHERE Invoice_Date BETWEEN '01/01/2013 00:00:00.000'
AND '01/01/2013 23:59:59.999'




Tally Tables - Performance Personified
String Splitting with True Performance
Best practices on how to ask questions
anthony.green
anthony.green
SSC Guru
SSC Guru (62K reputation)SSC Guru (62K reputation)SSC Guru (62K reputation)SSC Guru (62K reputation)SSC Guru (62K reputation)SSC Guru (62K reputation)SSC Guru (62K reputation)SSC Guru (62K reputation)

Group: General Forum Members
Points: 62786 Visits: 8598
Ed Wagner (1/17/2013)
If your field is a datetime data type, then you're comparing the datetime result of GetDate() against the datetime value of the field. So, nothing's going to match. I like the BETWEEN or <= and >= approach as well. That was you can avoid putting date parsing functions on the field (i.e.: to the left of the = sign) which would be a disaster for performance.

Effectively, you want use date functions that evaluate to something like this:


WHERE Invoice_Date BETWEEN '01/01/2013 00:00:00.000'
AND '01/01/2013 23:59:59.999'




That will equate to BETWEEN 01/01/2013 and 02/01/2013 due to the rounding of datetime.

You would want 01/01/2013 00:00:00.000 AND 01/01/2013 23:59:59.997 instead, unless your using datetime2

But always try to remember to qualify your dates as ISO formats so that SQL doesnt get confused or set the dateformat to the correct format

YYYY-MM-DDTHH:MM:SS.ms

Take 02/01/2013 is it 2nd Jan 2013 or 1st Feb 2013, depending who you ask you will get a different answer, where as if it follows an ISO standard there cannot be any confusion

http://en.wikipedia.org/wiki/ISO_8601



How to post data/code for the best help - Jeff Moden
Need a string splitter, try this - Jeff Moden
How to post performance problems - Gail Shaw
Managing Transaction Logs - Gail Shaw
Troubleshooting SQL Server: A Guide for the Accidental DBA - Jonathan Kehayias and Ted Krueger


dbman
dbman
SSCommitted
SSCommitted (1.8K reputation)SSCommitted (1.8K reputation)SSCommitted (1.8K reputation)SSCommitted (1.8K reputation)SSCommitted (1.8K reputation)SSCommitted (1.8K reputation)SSCommitted (1.8K reputation)SSCommitted (1.8K reputation)

Group: General Forum Members
Points: 1803 Visits: 1537
Thanks Anthony Green. That worked fine.
anthony.green
anthony.green
SSC Guru
SSC Guru (62K reputation)SSC Guru (62K reputation)SSC Guru (62K reputation)SSC Guru (62K reputation)SSC Guru (62K reputation)SSC Guru (62K reputation)SSC Guru (62K reputation)SSC Guru (62K reputation)

Group: General Forum Members
Points: 62786 Visits: 8598
ziako (1/17/2013)
Thanks Anthony Green. That worked fine.


No problem, glad I could assist.

May I suggest some further reading http://www.sqlservercentral.com/blogs/lynnpettis/2009/03/25/some-common-date-routines/
They may help you out with other date related issues you may run into.



How to post data/code for the best help - Jeff Moden
Need a string splitter, try this - Jeff Moden
How to post performance problems - Gail Shaw
Managing Transaction Logs - Gail Shaw
Troubleshooting SQL Server: A Guide for the Accidental DBA - Jonathan Kehayias and Ted Krueger


wolfkillj
wolfkillj
SSCertifiable
SSCertifiable (5.5K reputation)SSCertifiable (5.5K reputation)SSCertifiable (5.5K reputation)SSCertifiable (5.5K reputation)SSCertifiable (5.5K reputation)SSCertifiable (5.5K reputation)SSCertifiable (5.5K reputation)SSCertifiable (5.5K reputation)

Group: General Forum Members
Points: 5524 Visits: 2582
anthony.green (1/17/2013)
Ed Wagner (1/17/2013)
If your field is a datetime data type, then you're comparing the datetime result of GetDate() against the datetime value of the field. So, nothing's going to match. I like the BETWEEN or <= and >= approach as well. That was you can avoid putting date parsing functions on the field (i.e.: to the left of the = sign) which would be a disaster for performance.

Effectively, you want use date functions that evaluate to something like this:


WHERE Invoice_Date BETWEEN '01/01/2013 00:00:00.000'
AND '01/01/2013 23:59:59.999'




That will equate to BETWEEN 01/01/2013 and 02/01/2013 due to the rounding of datetime.

You would want 01/01/2013 00:00:00.000 AND 01/01/2013 23:59:59.997 instead, unless your using datetime2

But always try to remember to qualify your dates as ISO formats so that SQL doesnt get confused or set the dateformat to the correct format

YYYY-MM-DDTHH:MM:SS.ms

Take 02/01/2013 is it 2nd Jan 2013 or 1st Feb 2013, depending who you ask you will get a different answer, where as if it follows an ISO standard there cannot be any confusion

http://en.wikipedia.org/wiki/ISO_8601


It would be even better to specify start and end dates using the "half-open interval" model, like this:

WHERE DatetimeColumn >= '2013-01-01 00:00:00.000' AND DatetimeColumn < '2013-01-02 00:00:00.000'

This will return all values with a date component of 2013-01-01 with none of the ambiguity that can result from rounding the time component when evaluating the BETWEEN condition.

It's called a "half-open interval" because the "start" datetime is included in the range but the "end" datetime is not.

Jason Wolfkill
Blog: SQLSouth
Twitter: @SQLSouth
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