Click here to monitor SSC
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


datediff include 1 hour before midnight


datediff include 1 hour before midnight

Author
Message
Nooch
Nooch
Grasshopper
Grasshopper (12 reputation)Grasshopper (12 reputation)Grasshopper (12 reputation)Grasshopper (12 reputation)Grasshopper (12 reputation)Grasshopper (12 reputation)Grasshopper (12 reputation)Grasshopper (12 reputation)

Group: General Forum Members
Points: 12 Visits: 72
Hi,

I need to find all records for all 3 shifts in 1 day and the datediff below does not include the 1 hour before midnight (missing 1 hour for graveyard shift).

where DateDiff(day, Start_DateTime, '2014-04-07')=0 AND DateDiff(day, End_DateTime, '2014-04-07')=0

Thank You for you time.
Lynn Pettis
Lynn Pettis
SSC-Insane
SSC-Insane (24K reputation)SSC-Insane (24K reputation)SSC-Insane (24K reputation)SSC-Insane (24K reputation)SSC-Insane (24K reputation)SSC-Insane (24K reputation)SSC-Insane (24K reputation)SSC-Insane (24K reputation)

Group: General Forum Members
Points: 24200 Visits: 37964
awcrestview (4/8/2014)
Hi,

I need to find all records for all 3 shifts in 1 day and the datediff below does not include the 1 hour before midnight (missing 1 hour for graveyard shift).

where DateDiff(day, Start_DateTime, '2014-04-07')=0 AND DateDiff(day, End_DateTime, '2014-04-07')=0

Thank You for you time.


Based on the date 2014-04-07 what are the dates and times of the shifts you are trying to return.

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)
Nooch
Nooch
Grasshopper
Grasshopper (12 reputation)Grasshopper (12 reputation)Grasshopper (12 reputation)Grasshopper (12 reputation)Grasshopper (12 reputation)Grasshopper (12 reputation)Grasshopper (12 reputation)Grasshopper (12 reputation)

Group: General Forum Members
Points: 12 Visits: 72
Thank You for your reply.

I need records for user selected date. In this example I'm using 4/7/14.

The shifts are;
grave = 11pm to 7am
day = 7am to 3pm
swing = 3pm to 11pm

thanks
Nooch
Nooch
Grasshopper
Grasshopper (12 reputation)Grasshopper (12 reputation)Grasshopper (12 reputation)Grasshopper (12 reputation)Grasshopper (12 reputation)Grasshopper (12 reputation)Grasshopper (12 reputation)Grasshopper (12 reputation)

Group: General Forum Members
Points: 12 Visits: 72
The start_datetime for this example would be graveyard shift which starts at 11pm on 4/6/14.

Thank You
Lynn Pettis
Lynn Pettis
SSC-Insane
SSC-Insane (24K reputation)SSC-Insane (24K reputation)SSC-Insane (24K reputation)SSC-Insane (24K reputation)SSC-Insane (24K reputation)SSC-Insane (24K reputation)SSC-Insane (24K reputation)SSC-Insane (24K reputation)

Group: General Forum Members
Points: 24200 Visits: 37964
awcrestview (4/8/2014)
The start_datetime for this example would be graveyard shift which starts at 11pm on 4/6/14.

Thank You


Okay, so what you are looking for is the following based on a the date 2014-04-07 is this:

where startdate >= '2014-04-06 23:00' and enddate < '2014-04-07 23:00'

Is this a good paraphrase of what you need? If so, then something like this:

WHERE startdate >= dateadd(hour, -1, dateadd(day, datediff(day, 0, getdate()), 0)) and enddate < dateadd(hour, -1, dateadd(day, datediff(day, 0, getdate()), 1))


This assumes the getdate() returns '2014-04-07 hh:mm:nnn.nn'.

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)
Nooch
Nooch
Grasshopper
Grasshopper (12 reputation)Grasshopper (12 reputation)Grasshopper (12 reputation)Grasshopper (12 reputation)Grasshopper (12 reputation)Grasshopper (12 reputation)Grasshopper (12 reputation)Grasshopper (12 reputation)

Group: General Forum Members
Points: 12 Visits: 72
Lynn,

Thanks for you help Lynn, you're awesome. Below is from your recommendation with minor change to get what I needed.

WHERE start_datetime >= dateadd(hour, -1, dateadd(day, datediff(day, 0, (getdate)), 0)) and DateDiff(day, End_DateTime, 'getdate')=0
Lynn Pettis
Lynn Pettis
SSC-Insane
SSC-Insane (24K reputation)SSC-Insane (24K reputation)SSC-Insane (24K reputation)SSC-Insane (24K reputation)SSC-Insane (24K reputation)SSC-Insane (24K reputation)SSC-Insane (24K reputation)SSC-Insane (24K reputation)

Group: General Forum Members
Points: 24200 Visits: 37964
awcrestview (4/8/2014)
Lynn,

Thanks for you help Lynn, you're awesome. Below is from your recommendation with minor change to get what I needed.

WHERE start_datetime >= dateadd(hour, -1, dateadd(day, datediff(day, 0, (getdate)), 0)) and DateDiff(day, End_DateTime, 'getdate')=0



Just realize that this part of the where clause, DateDiff(day, End_DateTime, 'getdate') = 0, is not SARGable meaning you will not make use of any indexes. This part requires the every row needs to be tested to determine if the difference in days between End_DateTime and GETDATE() = 0.

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)
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