Please start any new threads on our new site at http://forums.sqlteam.com. We've got lots of great SQL Server experts to answer whatever question you can come up with.

Our new SQL Server Forums are live! Come on over! We've restricted the ability to create new threads on these forums.

SQL Server Forums
Profile | Active Topics | Members | Search | Forum FAQ
Username:
Password:
Save Password
Forgot your Password?

 All Forums
 SQL Server 2005 Forums
 Transact-SQL (2005)
 How to use Date Diff Function?
 Reply to Topic
 Printer Friendly
Author Previous Topic Topic Next Topic  

abhishek_kumar_rch
Starting Member

India
6 Posts

Posted - 05/02/2015 :  03:00:20  Show Profile  Reply with Quote
Hi,
I have added one webpage designed in ASP.Net with C# and sql server 2005 as database. There is table for user registration in which there is a column for user creation date time the data type of that column is date time .
I would like to fetch data of those user who have created profile within 7 days. For getting desired result I am trying this query.


select Name ,Profession,ProfileCreationDate from tblRegistration where DATEDIFF ( Day , '" + System.DateTime.Now + "',ProfileCreationDate)<7 order by ProfileCreationDate DESC


System.DateTime.Now is a function for getting current date time in C#

The query is neither giving error nor giving desired result please help me.

Kristen
Test

United Kingdom
22859 Posts

Posted - 05/02/2015 :  03:52:52  Show Profile  Reply with Quote
I would have done

WHERE ProfileCreationDate >= DATEADD(Day, -7, GetDate())

(GetDate() is a SQL function for current Date AND Time - so that will all happen at the SQL end, rather than based on the Web Server time. That only matters if the time is different on the Web Server and the SQL Server!! If the date/time for ProfileCreationDate is automatically added by SQL then I would user SQL time, if it is added by your APP instead then maybe I would use Web Server time. What if one is on Daylight Saving Time and the other not? Or the servers are in different countries?? Anyway, that may not be a problem you need to worry about!!!!)

Next problem is that DATEADD (and DATEDIFF) will add a DAY but keep the TIME part the same ... when you say "Last 7 days" I expect you mean "Any records in the last 7 days and today, so far" and that means starting at midnight 7 days ago.

For example if I do

SELECT	GetDate() AS TimeNow,
	DATEADD(Day, -7, GetDate()) AS TimeBefore

I get

TimeNow                 TimeBefore
----------------------- -----------------------
2015-05-02 08:50:03.893 2015-04-25 08:50:03.893

There are various ways of getting "Midnight" on a date, usually involving string manipulation, but this is the most efficient for SQL as it only uses integer maths, no [slower] string conversion

SELECT	GetDate() AS TimeNow,
	DATEADD(Day, 0, DATEDIFF(Day, 0, GetDate()) - 7)  AS TimeBefore

TimeNow                 TimeBefore
----------------------- -----------------------
2015-05-02 08:52:22.313 2015-04-25 00:00:00.000

so if your APP will use the Date/Time on the SQL Server then your code would need to be:

select Name ,Profession,ProfileCreationDate from tblRegistration 
where ProfileCreationDate >= DATEADD(Day, 0, DATEDIFF(Day, 0, GetDate()) - 7)
order by ProfileCreationDate DESC

Edited by - Kristen on 05/02/2015 03:56:09
Go to Top of Page
  Previous Topic Topic Next Topic  
 Reply to Topic
 Printer Friendly
Jump To:
SQL Server Forums © 2000-2009 SQLTeam Publishing, LLC Go To Top Of Page
This page was generated in 0.02 seconds. Powered By: Snitz Forums 2000