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 ««123»»

Query to find the start day of the week as Monday Expand / Collapse
Author
Message
Posted Tuesday, December 4, 2012 11:18 AM
SSCommitted

SSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommitted

Group: General Forum Members
Last Login: Yesterday @ 8:03 PM
Points: 1,669, Visits: 2,213
Lynn Pettis (12/4/2012)
Compare:


DECLARE @date DATE = '20121202';
SELECT
CASE WHEN datename(dw,@date) <> 'Sunday' THEN CONVERT(varchar(10), DATEADD(WK, DATEDIFF(WK, 0, @date), 0),
103) ELSE CONVERT(varchar(10), DATEADD(WK, DATEDIFF(WK, 0, @date), - 7), 103) END
go

DECLARE @date DATE = '20121203';
SELECT
CASE WHEN datename(dw,@date) <> 'Sunday' THEN CONVERT(varchar(10), DATEADD(WK, DATEDIFF(WK, 0, @date), 0),
103) ELSE CONVERT(varchar(10), DATEADD(WK, DATEDIFF(WK, 0, @date), - 7), 103) END
go

DECLARE @date DATE = '20121202';
select dateadd(wk, datediff(wk, 0, DATEADD(dd,-1,@Date)), 0);
GO

DECLARE @date DATE = '20121203';
select dateadd(wk, datediff(wk, 0, DATEADD(dd,-1,@Date)), 0);
GO




Yup, you have it right. I didn't get to see your post before I posted my answer. I'd sure like to understand a bit more about why that works. It's using the number of weeks since date zero through yesterday, then re-adding the same number of weeks to date zero, which suggests that perhaps the week is defined based on Monday ? Or is it Sunday, and thus why yesterday is used instead of today?



Steve
(aka sgmunson)

Internet ATM Machine
Post #1392635
Posted Tuesday, December 4, 2012 11:22 AM


SSC-Insane

SSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-Insane

Group: General Forum Members
Last Login: Today @ 8:34 PM
Points: 23,343, Visits: 32,079
sgmunson (12/4/2012)
Lynn Pettis (12/4/2012)
Compare:


DECLARE @date DATE = '20121202';
SELECT
CASE WHEN datename(dw,@date) <> 'Sunday' THEN CONVERT(varchar(10), DATEADD(WK, DATEDIFF(WK, 0, @date), 0),
103) ELSE CONVERT(varchar(10), DATEADD(WK, DATEDIFF(WK, 0, @date), - 7), 103) END
go

DECLARE @date DATE = '20121203';
SELECT
CASE WHEN datename(dw,@date) <> 'Sunday' THEN CONVERT(varchar(10), DATEADD(WK, DATEDIFF(WK, 0, @date), 0),
103) ELSE CONVERT(varchar(10), DATEADD(WK, DATEDIFF(WK, 0, @date), - 7), 103) END
go

DECLARE @date DATE = '20121202';
select dateadd(wk, datediff(wk, 0, DATEADD(dd,-1,@Date)), 0);
GO

DECLARE @date DATE = '20121203';
select dateadd(wk, datediff(wk, 0, DATEADD(dd,-1,@Date)), 0);
GO




Yup, you have it right. I didn't get to see your post before I posted my answer. I'd sure like to understand a bit more about why that works. It's using the number of weeks since date zero through yesterday, then re-adding the same number of weeks to date zero, which suggests that perhaps the week is defined based on Monday ? Or is it Sunday, and thus why yesterday is used instead of today?



Will explain tonight.



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)
Post #1392638
Posted Tuesday, December 4, 2012 12:47 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: 2 days ago @ 2:50 PM
Points: 3,135, Visits: 11,482
Lynn Pettis (12/4/2012)
Michael Valentine Jones (12/4/2012)
select
a.*,
Monday = dateadd(dd,(datediff(dd,-53690,a.DATE)/7)*7,-53690)
from
( -- Test Data
select [Date] = getdate()-2 union all
select [Date] = getdate()-1 union all
select [Date] = getdate() union all
select [Date] = getdate()+1 union all
select [Date] = getdate()+2 union all
select [Date] = getdate()+3 union all
select [Date] = getdate()+4 union all
select [Date] = getdate()+5 union all
select [Date] = getdate()+6 union all
select [Date] = getdate()+7 union all
select [Date] = getdate()+8
) a
order by
a.[Date]

Results:
Date                    Monday
----------------------- -----------------------
2012-12-02 13:05:22.770 2012-11-26 00:00:00.000
2012-12-03 13:05:22.803 2012-12-03 00:00:00.000
2012-12-04 13:05:22.803 2012-12-03 00:00:00.000
2012-12-05 13:05:22.803 2012-12-03 00:00:00.000
2012-12-06 13:05:22.803 2012-12-03 00:00:00.000
2012-12-07 13:05:22.803 2012-12-03 00:00:00.000
2012-12-08 13:05:22.803 2012-12-03 00:00:00.000
2012-12-09 13:05:22.803 2012-12-03 00:00:00.000
2012-12-10 13:05:22.803 2012-12-10 00:00:00.000
2012-12-11 13:05:22.803 2012-12-10 00:00:00.000
2012-12-12 13:05:22.803 2012-12-10 00:00:00.000



Or:


select
a.*,
Monday = dateadd(wk, datediff(wk, 0, DATEADD(dd,-1,a.Date)), 0)
from
( -- Test Data
select [Date] = getdate()-2 union all
select [Date] = getdate()-1 union all
select [Date] = getdate() union all
select [Date] = getdate()+1 union all
select [Date] = getdate()+2 union all
select [Date] = getdate()+3 union all
select [Date] = getdate()+4 union all
select [Date] = getdate()+5 union all
select [Date] = getdate()+6 union all
select [Date] = getdate()+7 union all
select [Date] = getdate()+8
) a
order by
a.[Date]




Not completely the same, though:
select
a.*,
Monday = dateadd(dd,(datediff(dd,-53690,a.DATE)/7)*7,-53690)
from
( select [Date] = convert(datetime,'17530101') ) a

select
a.*,
Monday = dateadd(wk, datediff(wk, 0, DATEADD(dd,-1,a.Date)), 0)
from
( select [Date] = convert(datetime,'17530101') )

Results:
Date                    Monday
----------------------- -----------------------
1753-01-01 00:00:00.000 1753-01-01 00:00:00.000

(1 row(s) affected)

Date Monday
----------------------- -----------------------
Msg 517, Level 16, State 1, Line 7
Adding a value to a 'datetime' column caused an overflow.
Post #1392667
Posted Tuesday, December 4, 2012 4:09 PM


SSC-Insane

SSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-Insane

Group: General Forum Members
Last Login: Today @ 8:34 PM
Points: 23,343, Visits: 32,079
Michael Valentine Jones (12/4/2012)
Lynn Pettis (12/4/2012)
Michael Valentine Jones (12/4/2012)
select
a.*,
Monday = dateadd(dd,(datediff(dd,-53690,a.DATE)/7)*7,-53690)
from
( -- Test Data
select [Date] = getdate()-2 union all
select [Date] = getdate()-1 union all
select [Date] = getdate() union all
select [Date] = getdate()+1 union all
select [Date] = getdate()+2 union all
select [Date] = getdate()+3 union all
select [Date] = getdate()+4 union all
select [Date] = getdate()+5 union all
select [Date] = getdate()+6 union all
select [Date] = getdate()+7 union all
select [Date] = getdate()+8
) a
order by
a.[Date]

Results:
Date                    Monday
----------------------- -----------------------
2012-12-02 13:05:22.770 2012-11-26 00:00:00.000
2012-12-03 13:05:22.803 2012-12-03 00:00:00.000
2012-12-04 13:05:22.803 2012-12-03 00:00:00.000
2012-12-05 13:05:22.803 2012-12-03 00:00:00.000
2012-12-06 13:05:22.803 2012-12-03 00:00:00.000
2012-12-07 13:05:22.803 2012-12-03 00:00:00.000
2012-12-08 13:05:22.803 2012-12-03 00:00:00.000
2012-12-09 13:05:22.803 2012-12-03 00:00:00.000
2012-12-10 13:05:22.803 2012-12-10 00:00:00.000
2012-12-11 13:05:22.803 2012-12-10 00:00:00.000
2012-12-12 13:05:22.803 2012-12-10 00:00:00.000



Or:


select
a.*,
Monday = dateadd(wk, datediff(wk, 0, DATEADD(dd,-1,a.Date)), 0)
from
( -- Test Data
select [Date] = getdate()-2 union all
select [Date] = getdate()-1 union all
select [Date] = getdate() union all
select [Date] = getdate()+1 union all
select [Date] = getdate()+2 union all
select [Date] = getdate()+3 union all
select [Date] = getdate()+4 union all
select [Date] = getdate()+5 union all
select [Date] = getdate()+6 union all
select [Date] = getdate()+7 union all
select [Date] = getdate()+8
) a
order by
a.[Date]




Not completely the same, though:
select
a.*,
Monday = dateadd(dd,(datediff(dd,-53690,a.DATE)/7)*7,-53690)
from
( select [Date] = convert(datetime,'17530101') ) a

select
a.*,
Monday = dateadd(wk, datediff(wk, 0, DATEADD(dd,-1,a.Date)), 0)
from
( select [Date] = convert(datetime,'17530101') )

Results:
Date                    Monday
----------------------- -----------------------
1753-01-01 00:00:00.000 1753-01-01 00:00:00.000

(1 row(s) affected)

Date Monday
----------------------- -----------------------
Msg 517, Level 16, State 1, Line 7
Adding a value to a 'datetime' column caused an overflow.


Not saying that there aren't, but most database applications don't nned to go that far back in time. I'd call that an edge case.



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)
Post #1392735
Posted Tuesday, December 4, 2012 5:08 PM


SSC-Dedicated

SSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-Dedicated

Group: General Forum Members
Last Login: Today @ 4:24 PM
Points: 36,995, Visits: 31,522
Then substitute a 0 for Michael's -53690.


That, not withstanding, it's always the "edge cases" that cause panic stricken calls at 3 in the morning.


--Jeff Moden
"RBAR is pronounced "ree-bar" and is a "Modenism" for "Row-By-Agonizing-Row".

First step towards the paradigm shift of writing Set Based code:
Stop thinking about what you want to do to a row... think, instead, of what you want to do to a column."

(play on words) "Just because you CAN do something in T-SQL, doesn't mean you SHOULDN'T." --22 Aug 2013

Helpful Links:
How to post code problems
How to post performance problems
Post #1392741
Posted Tuesday, December 4, 2012 5:48 PM


SSC-Insane

SSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-Insane

Group: General Forum Members
Last Login: Today @ 8:34 PM
Points: 23,343, Visits: 32,079
Jeff Moden (12/4/2012)
Then substitute a 0 for Michael's -53690.


That, not withstanding, it's always the "edge cases" that cause panic stricken calls at 3 in the morning.


If I have to worry about dates that far back, I'll convert everything to datetme2 since this is a SQL Server 2008 forum. That way I can go back further. Only problem then is what calendar do you really use? Heck, if I remember correctly we used different calendars into the early 1900's didn't we?



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)
Post #1392755
Posted Tuesday, December 4, 2012 5:57 PM


SSC-Insane

SSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-Insane

Group: General Forum Members
Last Login: Today @ 8:34 PM
Points: 23,343, Visits: 32,079
sgmunson (12/4/2012)
Lynn Pettis (12/4/2012)
Compare:


DECLARE @date DATE = '20121202';
SELECT
CASE WHEN datename(dw,@date) <> 'Sunday' THEN CONVERT(varchar(10), DATEADD(WK, DATEDIFF(WK, 0, @date), 0),
103) ELSE CONVERT(varchar(10), DATEADD(WK, DATEDIFF(WK, 0, @date), - 7), 103) END
go

DECLARE @date DATE = '20121203';
SELECT
CASE WHEN datename(dw,@date) <> 'Sunday' THEN CONVERT(varchar(10), DATEADD(WK, DATEDIFF(WK, 0, @date), 0),
103) ELSE CONVERT(varchar(10), DATEADD(WK, DATEDIFF(WK, 0, @date), - 7), 103) END
go

DECLARE @date DATE = '20121202';
select dateadd(wk, datediff(wk, 0, DATEADD(dd,-1,@Date)), 0);
GO

DECLARE @date DATE = '20121203';
select dateadd(wk, datediff(wk, 0, DATEADD(dd,-1,@Date)), 0);
GO




Yup, you have it right. I didn't get to see your post before I posted my answer. I'd sure like to understand a bit more about why that works. It's using the number of weeks since date zero through yesterday, then re-adding the same number of weeks to date zero, which suggests that perhaps the week is defined based on Monday ? Or is it Sunday, and thus why yesterday is used instead of today?



Why the code I posted returns this weeks Monday date is because 1900-01-01 is a Monday. I subtracted 1 in the calculations on tthis thread because the OP waanted the Sunday prior to the Monday date in the previous week. If it is Monday, and I subtract 1 from it and perform the the calculation used in my posts, it returns the Monday of that week.

I would suggest playing with the date calculatioins and see what other tidbits you might discover. If you go to my blog on ssc, you will find more date calculations there as well.



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)
Post #1392756
Posted Tuesday, December 4, 2012 10:26 PM


SSC-Dedicated

SSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-Dedicated

Group: General Forum Members
Last Login: Today @ 4:24 PM
Points: 36,995, Visits: 31,522
Lynn Pettis (12/4/2012)
Jeff Moden (12/4/2012)
Then substitute a 0 for Michael's -53690.


That, not withstanding, it's always the "edge cases" that cause panic stricken calls at 3 in the morning.


If I have to worry about dates that far back, I'll convert everything to datetme2 since this is a SQL Server 2008 forum. That way I can go back further. Only problem then is what calendar do you really use? Heck, if I remember correctly we used different calendars into the early 1900's didn't we?


Since not all countries adopted the Gregorian calendar at the same time and the Julian calendar (which was mathematically incorrect compared to Earth's orbit) was in effect before that, I suspect a simple switch to DATETIME2 would produce some good inaccuracies.

Just to be sure, I wasn't challenging you. I meant only to explain that Michaeal does with dates what a lot of us (including you and me) do with a lot of other things... make the code mostly bullet-proof in the face of future unknown domains and scalability especially since we don't know who's going to use our code for what once they find it.

Still, I'm like you in that I prefer to use the 0 date reference for a couple of reasons. It's shorter to type, requires literally "0" memory for me to remember, and allows for negative math without running into the "bottom" of the allowed timeline.

Shifting gears, I've always wanted to know what the performance of the integer trick that Micheal (I use it too because it's easy for me to remember) uses for such week calculation and the methods that avoid direct math on dates. Admittedly, both methods are very fast and it takes millions of rows (which I work with in about a 3rd of all the queries I have to write) to actually see a difference but every millisecond counts if you have to do such a thing with many columns across many tables for such a thing. I've long suspected that the integer method would squeak past (9% faster in this case) the 3 part method but have never taken the time to prove it until now.

Here's the test code. No... I don't trust SET STATISTICS any more.

--===== Conditionally drop the test table to make reruns in SSMS easier.
IF OBJECT_ID('tempdb..#SomeTable','U') IS NOT NULL
DROP TABLE #SomeTable
;
--===== Build and ppulate the test table on-the-fly.
SELECT TOP 5000000
SomeDate = DATEADD(dd,ABS(CHECKSUM(NEWID()))%DATEDIFF(dd,'1900','2000'),'1900')
INTO #SomeTable
FROM master.sys.all_columns ac1
CROSS JOIN master.sys.all_columns ac2
;
GO
PRINT '--===== Performance Baseline Simple Select Method =====--'
DBCC FREEPROCCACHE;
DBCC DROPCLEANBUFFERS;
DECLARE @BitBucket DATETIME,
@StartTime DATETIME;

SELECT @StartTime = GETDATE();
SELECT @BitBucket = SomeDate
FROM #SomeTable
;
PRINT DATEDIFF(ms,@StartTime, GETDATE());
GO
PRINT '--===== Performance -53690 Integer Math Function Method =====--'
DBCC FREEPROCCACHE;
DBCC DROPCLEANBUFFERS;
DECLARE @BitBucket DATETIME,
@StartTime DATETIME;

SELECT @StartTime = GETDATE();
SELECT @BitBucket = DATEADD(dd,(DATEDIFF(dd,-53690,SomeDate)/7)*7,-53690)
FROM #SomeTable
;
PRINT DATEDIFF(ms,@StartTime, GETDATE());
GO
PRINT '--===== Performance 0 Integer Math Function Method =====--'
DBCC FREEPROCCACHE;
DBCC DROPCLEANBUFFERS;
DECLARE @BitBucket DATETIME,
@StartTime DATETIME;

SELECT @StartTime = GETDATE();
SELECT @BitBucket = DATEADD(dd,(DATEDIFF(dd,0,SomeDate)/7)*7,0)
FROM #SomeTable
;
PRINT DATEDIFF(ms,@StartTime, GETDATE());
GO
PRINT '--===== Performance 3 DATETIME Function Method =====--'
DBCC FREEPROCCACHE;
DBCC DROPCLEANBUFFERS;
DECLARE @BitBucket DATETIME,
@StartTime DATETIME;

SELECT @StartTime = GETDATE();
SELECT @BitBucket = DATEADD(wk, DATEDIFF(wk, 0, DATEADD(dd,-1,SomeDate)), 0)
FROM #SomeTable
;
PRINT DATEDIFF(ms,@StartTime, GETDATE());
GO


Here are the run results on my humble 2005 desktop box.

--===== Performance Baseline Simple Select Method =====--
DBCC execution completed. If DBCC printed error messages, contact your system administrator.
DBCC execution completed. If DBCC printed error messages, contact your system administrator.
2850
--===== Performance -53690 Integer Math Function Method =====--
DBCC execution completed. If DBCC printed error messages, contact your system administrator.
DBCC execution completed. If DBCC printed error messages, contact your system administrator.
4830
--===== Performance 0 Integer Math Function Method =====--
DBCC execution completed. If DBCC printed error messages, contact your system administrator.
DBCC execution completed. If DBCC printed error messages, contact your system administrator.
4833
--===== Performance 3 DATETIME Function Method =====--
DBCC execution completed. If DBCC printed error messages, contact your system administrator.
DBCC execution completed. If DBCC printed error messages, contact your system administrator.
5263





--Jeff Moden
"RBAR is pronounced "ree-bar" and is a "Modenism" for "Row-By-Agonizing-Row".

First step towards the paradigm shift of writing Set Based code:
Stop thinking about what you want to do to a row... think, instead, of what you want to do to a column."

(play on words) "Just because you CAN do something in T-SQL, doesn't mean you SHOULDN'T." --22 Aug 2013

Helpful Links:
How to post code problems
How to post performance problems
Post #1392786
Posted Wednesday, December 5, 2012 2:01 AM
SSC-Enthusiastic

SSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-Enthusiastic

Group: General Forum Members
Last Login: Friday, August 1, 2014 8:41 AM
Points: 101, Visits: 437
Thanks all for ur reply!
Post #1392838
Posted Wednesday, December 5, 2012 7:51 AM


SSC-Insane

SSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-Insane

Group: General Forum Members
Last Login: Today @ 8:34 PM
Points: 23,343, Visits: 32,079
Jeff Moden (12/4/2012)
Lynn Pettis (12/4/2012)
Jeff Moden (12/4/2012)
Then substitute a 0 for Michael's -53690.


That, not withstanding, it's always the "edge cases" that cause panic stricken calls at 3 in the morning.


If I have to worry about dates that far back, I'll convert everything to datetme2 since this is a SQL Server 2008 forum. That way I can go back further. Only problem then is what calendar do you really use? Heck, if I remember correctly we used different calendars into the early 1900's didn't we?


Since not all countries adopted the Gregorian calendar at the same time and the Julian calendar (which was mathematically incorrect compared to Earth's orbit) was in effect before that, I suspect a simple switch to DATETIME2 would produce some good inaccuracies.

Just to be sure, I wasn't challenging you. I meant only to explain that Michaeal does with dates what a lot of us (including you and me) do with a lot of other things... make the code mostly bullet-proof in the face of future unknown domains and scalability especially since we don't know who's going to use our code for what once they find it.

Still, I'm like you in that I prefer to use the 0 date reference for a couple of reasons. It's shorter to type, requires literally "0" memory for me to remember, and allows for negative math without running into the "bottom" of the allowed timeline.

Shifting gears, I've always wanted to know what the performance of the integer trick that Micheal (I use it too because it's easy for me to remember) uses for such week calculation and the methods that avoid direct math on dates. Admittedly, both methods are very fast and it takes millions of rows (which I work with in about a 3rd of all the queries I have to write) to actually see a difference but every millisecond counts if you have to do such a thing with many columns across many tables for such a thing. I've long suspected that the integer method would squeak past (9% faster in this case) the 3 part method but have never taken the time to prove it until now.

Here's the test code. No... I don't trust SET STATISTICS any more.

--===== Conditionally drop the test table to make reruns in SSMS easier.
IF OBJECT_ID('tempdb..#SomeTable','U') IS NOT NULL
DROP TABLE #SomeTable
;
--===== Build and ppulate the test table on-the-fly.
SELECT TOP 5000000
SomeDate = DATEADD(dd,ABS(CHECKSUM(NEWID()))%DATEDIFF(dd,'1900','2000'),'1900')
INTO #SomeTable
FROM master.sys.all_columns ac1
CROSS JOIN master.sys.all_columns ac2
;
GO
PRINT '--===== Performance Baseline Simple Select Method =====--'
DBCC FREEPROCCACHE;
DBCC DROPCLEANBUFFERS;
DECLARE @BitBucket DATETIME,
@StartTime DATETIME;

SELECT @StartTime = GETDATE();
SELECT @BitBucket = SomeDate
FROM #SomeTable
;
PRINT DATEDIFF(ms,@StartTime, GETDATE());
GO
PRINT '--===== Performance -53690 Integer Math Function Method =====--'
DBCC FREEPROCCACHE;
DBCC DROPCLEANBUFFERS;
DECLARE @BitBucket DATETIME,
@StartTime DATETIME;

SELECT @StartTime = GETDATE();
SELECT @BitBucket = DATEADD(dd,(DATEDIFF(dd,-53690,SomeDate)/7)*7,-53690)
FROM #SomeTable
;
PRINT DATEDIFF(ms,@StartTime, GETDATE());
GO
PRINT '--===== Performance 0 Integer Math Function Method =====--'
DBCC FREEPROCCACHE;
DBCC DROPCLEANBUFFERS;
DECLARE @BitBucket DATETIME,
@StartTime DATETIME;

SELECT @StartTime = GETDATE();
SELECT @BitBucket = DATEADD(dd,(DATEDIFF(dd,0,SomeDate)/7)*7,0)
FROM #SomeTable
;
PRINT DATEDIFF(ms,@StartTime, GETDATE());
GO
PRINT '--===== Performance 3 DATETIME Function Method =====--'
DBCC FREEPROCCACHE;
DBCC DROPCLEANBUFFERS;
DECLARE @BitBucket DATETIME,
@StartTime DATETIME;

SELECT @StartTime = GETDATE();
SELECT @BitBucket = DATEADD(wk, DATEDIFF(wk, 0, DATEADD(dd,-1,SomeDate)), 0)
FROM #SomeTable
;
PRINT DATEDIFF(ms,@StartTime, GETDATE());
GO


Here are the run results on my humble 2005 desktop box.

--===== Performance Baseline Simple Select Method =====--
DBCC execution completed. If DBCC printed error messages, contact your system administrator.
DBCC execution completed. If DBCC printed error messages, contact your system administrator.
2850
--===== Performance -53690 Integer Math Function Method =====--
DBCC execution completed. If DBCC printed error messages, contact your system administrator.
DBCC execution completed. If DBCC printed error messages, contact your system administrator.
4830
--===== Performance 0 Integer Math Function Method =====--
DBCC execution completed. If DBCC printed error messages, contact your system administrator.
DBCC execution completed. If DBCC printed error messages, contact your system administrator.
4833
--===== Performance 3 DATETIME Function Method =====--
DBCC execution completed. If DBCC printed error messages, contact your system administrator.
DBCC execution completed. If DBCC printed error messages, contact your system administrator.
5263





Jeff,

I know you weren't challenging me, that is part of the problem with text based communication, you miss out on tone of voice and body language for thos subtle clues as to the real meaning of what is said.

With that, however, you are constantly challenging me to become better at what I do. In another thread I said you were the Mentor of the Year. That's wrong. I should have said the Mentor of the Years as you you have done this for many years. I can honestly say you have been a big part of my learning since 2005. You and several others on ssc to be sure. I just hope I have been able to help others as much as you have.



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)
Post #1393022
« Prev Topic | Next Topic »

Add to briefcase ««123»»

Permissions Expand / Collapse