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


A Simple Formula to Calculate the ISO Week Number


A Simple Formula to Calculate the ISO Week Number

Author
Message
Steven Willis
Steven Willis
SSC-Addicted
SSC-Addicted (477 reputation)SSC-Addicted (477 reputation)SSC-Addicted (477 reputation)SSC-Addicted (477 reputation)SSC-Addicted (477 reputation)SSC-Addicted (477 reputation)SSC-Addicted (477 reputation)SSC-Addicted (477 reputation)

Group: General Forum Members
Points: 477 Visits: 1721
Jeff, just FYI...I created the million row table on my slow laptop and tested the code from your article. With a normal SELECT statement it took appx 19-22 secs per run to get a million rows.

Now out of curiosity, I whipped up an iTVF and ran that against the data with a cross apply and it did NOT perform well. Something on the order of 2 minutes or more. That just goes to show that iTVFs are not always the answer. I also re-tested after adding a non-clustered index to the temp table. That dropped about 3 seconds off the ordinary SELECT and about 10 seconds when using the iTVF.

I tried the iTVF both with a WITH SELECT/INSERT INTO and an garden-variety INSERT INTO SELECT and the WITH statement version was the slowest.

Not sure what use anyone might have with that information, but that's my report! ;-)

 


 
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: 24173 Visits: 37940
Steven Willis (4/8/2013)
Jeff, just FYI...I created the million row table on my slow laptop and tested the code from your article. With a normal SELECT statement it took appx 19-22 secs per run to get a million rows.

Now out of curiosity, I whipped up an iTVF and ran that against the data with a cross apply and it did NOT perform well. Something on the order of 2 minutes or more. That just goes to show that iTVFs are not always the answer. I also re-tested after adding a non-clustered index to the temp table. That dropped about 3 seconds off the ordinary SELECT and about 10 seconds when using the iTVF.

I tried the iTVF both with a WITH SELECT/INSERT INTO and an garden-variety INSERT INTO SELECT and the WITH statement version was the slowest.

Not sure what use anyone might have with that information, but that's my report! ;-)

 


 


Could you post your code, including the itvf you created?

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)
Steven Willis
Steven Willis
SSC-Addicted
SSC-Addicted (477 reputation)SSC-Addicted (477 reputation)SSC-Addicted (477 reputation)SSC-Addicted (477 reputation)SSC-Addicted (477 reputation)SSC-Addicted (477 reputation)SSC-Addicted (477 reputation)SSC-Addicted (477 reputation)

Group: General Forum Members
Points: 477 Visits: 1721
Lynn Pettis (4/8/2013)
Steven Willis (4/8/2013)
Jeff, just FYI...I created the million row table on my slow laptop and tested the code from your article. With a normal SELECT statement it took appx 19-22 secs per run to get a million rows.

Now out of curiosity, I whipped up an iTVF and ran that against the data with a cross apply and it did NOT perform well. Something on the order of 2 minutes or more. That just goes to show that iTVFs are not always the answer. I also re-tested after adding a non-clustered index to the temp table. That dropped about 3 seconds off the ordinary SELECT and about 10 seconds when using the iTVF.

I tried the iTVF both with a WITH SELECT/INSERT INTO and an garden-variety INSERT INTO SELECT and the WITH statement version was the slowest.

Not sure what use anyone might have with that information, but that's my report! ;-)
 

Could you post your code, including the itvf you created?


Jeff's test script:



--===== Conditionally drop the test table to make reruns in SSMS easier.
IF OBJECT_ID('tempdb..#TestTable','U') IS NOT NULL
DROP TABLE #TestTable
;
--===== Create and populate a million row test table with random dates/times
-- where (01 Jan 2000) <= Date < (01 Jan 2020)
SELECT TOP 1000000
Date = CAST(RAND(CHECKSUM(NEWID()))*DATEDIFF(dd,'2000','2020')+DATEDIFF(dd,0,'2000') AS DATETIME)
INTO #TestTable
FROM master.sys.all_columns ac1
CROSS JOIN master.sys.all_columns ac2
;
GO






SELECT
tvf.*
FROM
#TestTable tt
CROSS APPLY
dbo.itvfGetWeekNumberFromDate_ISO(tt.Date) tvf






CREATE FUNCTION [dbo].[itvfGetWeekNumberFromDate_ISO]
(
@dDate DATETIME
)
RETURNS @WeekNumber TABLE
(
[Date] DATE NULL
,[DayOfWeek] VARCHAR(20) NULL
,[ISOWeek] INT NULL
)
WITH SCHEMABINDING
AS
BEGIN

/*
SELECT * FROM dbo.itvfGetWeekNumberFromDate_ISO('2009-12-24')
*/

;WITH cte AS
(
SELECT
CONVERT(VARCHAR(20),@dDate,120) AS [Date]
,LEFT(DATENAME(dw,@dDate),9) AS [DayOfWeek]
,(DATEPART(dy,DATEDIFF(dd,0,@dDate)/7*7+3)+6)/7 AS [ISOWeek]
)
INSERT INTO @WeekNumber
SELECT
Date
,DayOfWeek
,ISOWeek
FROM
cte

RETURN

END






CREATE FUNCTION [dbo].[itvfGetWeekNumberFromDate_ISO_v2]
(
@dDate DATETIME
)
RETURNS @WeekNumber TABLE
(
[Date] DATE NULL
,[DayOfWeek] VARCHAR(20) NULL
,[ISOWeek] INT NULL
)
WITH SCHEMABINDING
AS
BEGIN

/*
SELECT * FROM dbo.itvfGetWeekNumberFromDate_ISO_v2('2009-12-24')
*/

INSERT INTO @WeekNumber
SELECT
CONVERT(VARCHAR(20),@dDate,120) AS [Date]
,LEFT(DATENAME(dw,@dDate),9) AS [DayOfWeek]
,(DATEPART(dy,DATEDIFF(dd,0,@dDate)/7*7+3)+6)/7 AS [ISOWeek]

RETURN

END






 
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: 24173 Visits: 37940
Steven Willis (4/8/2013)
Lynn Pettis (4/8/2013)
Steven Willis (4/8/2013)
Jeff, just FYI...I created the million row table on my slow laptop and tested the code from your article. With a normal SELECT statement it took appx 19-22 secs per run to get a million rows.

Now out of curiosity, I whipped up an iTVF and ran that against the data with a cross apply and it did NOT perform well. Something on the order of 2 minutes or more. That just goes to show that iTVFs are not always the answer. I also re-tested after adding a non-clustered index to the temp table. That dropped about 3 seconds off the ordinary SELECT and about 10 seconds when using the iTVF.

I tried the iTVF both with a WITH SELECT/INSERT INTO and an garden-variety INSERT INTO SELECT and the WITH statement version was the slowest.

Not sure what use anyone might have with that information, but that's my report! ;-)
 

Could you post your code, including the itvf you created?


Jeff's test script:



--===== Conditionally drop the test table to make reruns in SSMS easier.
IF OBJECT_ID('tempdb..#TestTable','U') IS NOT NULL
DROP TABLE #TestTable
;
--===== Create and populate a million row test table with random dates/times
-- where (01 Jan 2000) <= Date < (01 Jan 2020)
SELECT TOP 1000000
Date = CAST(RAND(CHECKSUM(NEWID()))*DATEDIFF(dd,'2000','2020')+DATEDIFF(dd,0,'2000') AS DATETIME)
INTO #TestTable
FROM master.sys.all_columns ac1
CROSS JOIN master.sys.all_columns ac2
;
GO






SELECT
tvf.*
FROM
#TestTable tt
CROSS APPLY
dbo.itvfGetWeekNumberFromDate_ISO(tt.Date) tvf






CREATE FUNCTION [dbo].[itvfGetWeekNumberFromDate_ISO]
(
@dDate DATETIME
)
RETURNS @WeekNumber TABLE
(
[Date] DATE NULL
,[DayOfWeek] VARCHAR(20) NULL
,[ISOWeek] INT NULL
)
WITH SCHEMABINDING
AS
BEGIN

/*
SELECT * FROM dbo.itvfGetWeekNumberFromDate_ISO('2009-12-24')
*/

;WITH cte AS
(
SELECT
CONVERT(VARCHAR(20),@dDate,120) AS [Date]
,LEFT(DATENAME(dw,@dDate),9) AS [DayOfWeek]
,(DATEPART(dy,DATEDIFF(dd,0,@dDate)/7*7+3)+6)/7 AS [ISOWeek]
)
INSERT INTO @WeekNumber
SELECT
Date
,DayOfWeek
,ISOWeek
FROM
cte

RETURN

END






CREATE FUNCTION [dbo].[itvfGetWeekNumberFromDate_ISO_v2]
(
@dDate DATETIME
)
RETURNS @WeekNumber TABLE
(
[Date] DATE NULL
,[DayOfWeek] VARCHAR(20) NULL
,[ISOWeek] INT NULL
)
WITH SCHEMABINDING
AS
BEGIN

/*
SELECT * FROM dbo.itvfGetWeekNumberFromDate_ISO_v2('2009-12-24')
*/

INSERT INTO @WeekNumber
SELECT
CONVERT(VARCHAR(20),@dDate,120) AS [Date]
,LEFT(DATENAME(dw,@dDate),9) AS [DayOfWeek]
,(DATEPART(dy,DATEDIFF(dd,0,@dDate)/7*7+3)+6)/7 AS [ISOWeek]

RETURN

END






 


I hate to be the bearer of bad news but your function is not an inline table valued function, it is a multi-statement table valued function.



The following is your function rewritten as an inline table valued function:



CREATE FUNCTION [dbo].[itvfGetWeekNumberFromDate_ISO_v2]
(
@dDate DATETIME
)
RETURNS TABLE
WITH SCHEMABINDING
AS
RETURN SELECT
CONVERT(VARCHAR(20),@dDate,120) AS [Date],
LEFT(DATENAME(dw,@dDate),9) AS [DayOfWeek],
(DATEPART(dy,DATEDIFF(dd,0,@dDate)/7*7+3)+6)/7 AS [ISOWeek];

GO



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)
Jeff Moden
Jeff Moden
SSC-Forever
SSC-Forever (45K reputation)SSC-Forever (45K reputation)SSC-Forever (45K reputation)SSC-Forever (45K reputation)SSC-Forever (45K reputation)SSC-Forever (45K reputation)SSC-Forever (45K reputation)SSC-Forever (45K reputation)

Group: General Forum Members
Points: 45002 Visits: 39880
Spot on, Lynn. Thanks for the cover. Busy 20 hour day at work yesterday.

--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.
Although they tell us that they want it real bad, our primary goal is to ensure that we dont actually give it to them that way.
Although change is inevitable, change for the better is not.
Just because you can do something in PowerShell, doesnt mean you should. Wink

Helpful Links:
How to post code problems
How to post performance problems
Forum FAQs
Steven Willis
Steven Willis
SSC-Addicted
SSC-Addicted (477 reputation)SSC-Addicted (477 reputation)SSC-Addicted (477 reputation)SSC-Addicted (477 reputation)SSC-Addicted (477 reputation)SSC-Addicted (477 reputation)SSC-Addicted (477 reputation)SSC-Addicted (477 reputation)

Group: General Forum Members
Points: 477 Visits: 1721
Lynn Pettis (4/8/2013)
I hate to be the bearer of bad news but your function is not an inline table valued function, it is a multi-statement table valued function.

The following is your function rewritten as an inline table valued function:



CREATE FUNCTION [dbo].[itvfGetWeekNumberFromDate_ISO_v2]
(
@dDate DATETIME
)
RETURNS TABLE
WITH SCHEMABINDING
AS
RETURN SELECT
CONVERT(VARCHAR(20),@dDate,120) AS [Date],
LEFT(DATENAME(dw,@dDate),9) AS [DayOfWeek],
(DATEPART(dy,DATEDIFF(dd,0,@dDate)/7*7+3)+6)/7 AS [ISOWeek];

GO


Lynn, of course you're correct. Too many late hours and not enough sleep. Blush

But I tested the iTVF against the mlTVF and really found no difference. Again, surprising results.



SELECT
CONVERT(VARCHAR(20),tt.Date,120) AS [Date]
,DATENAME(weekday,tt.Date) AS [DayOfWeek]
,(DATEPART(dy,DATEDIFF(dd,0,tt.Date) / 7 * 7 + 3) + 6) / 7 AS [ISOWeek]
FROM
#TestTable tt








CREATE FUNCTION [dbo].[itvfGetWeekNumberFromDate_ISO]
(
@dDate DATETIME
)
RETURNS @WeekNumber TABLE
(
[Date] DATE NULL
,[DayOfWeek] VARCHAR(20) NULL
,[ISOWeek] INT NULL
)
WITH SCHEMABINDING
AS
BEGIN

INSERT INTO @WeekNumber
SELECT
CONVERT(VARCHAR(20),@dDate,120) AS [Date]
,LEFT(DATENAME(dw,@dDate),9) AS [DayOfWeek]
,(DATEPART(dy,DATEDIFF(dd,0,@dDate)/7*7+3)+6)/7 AS [ISOWeek]

RETURN

END
GO


SELECT
tvf.*
FROM
#TestTable tt
CROSS APPLY
dbo.itvfGetWeekNumberFromDate_ISO(tt.date) tvf









CREATE FUNCTION [dbo].[itvfGetWeekNumberFromDate_ISO_v2]
(@dDate DATETIME)
RETURNS TABLE
WITH SCHEMABINDING
AS
RETURN
SELECT
CONVERT(VARCHAR(20),@dDate,120) AS [Date]
,LEFT(DATENAME(dw,@dDate),9) AS [DayOfWeek]
,(DATEPART(dy,DATEDIFF(dd,0,@dDate) / 7 * 7 + 3) + 6) / 7 AS [ISOWeek] ;

GO


SELECT
tvf.*
FROM
#TestTable tt
CROSS APPLY
dbo.itvfGetWeekNumberFromDate_ISO_v2(tt.date) tvf







 
Attachments
ISO_DATE_STATS3.PNG (179 views, 24.00 KB)
ISO_DATE_STATS2.PNG (179 views, 28.00 KB)
ISO_DATE_STATS1.PNG (175 views, 28.00 KB)
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: 24173 Visits: 37940
Create an empty database and run the following:



--===== Conditionally drop the test table to make reruns in SSMS easier.
IF OBJECT_ID('tempdb..#TestTable','U') IS NOT NULL
DROP TABLE #TestTable
;
--===== Create and populate a million row test table with random dates/times
-- where (01 Jan 2000) <= Date < (01 Jan 2020)
SELECT TOP 1000000
Date = CAST(RAND(CHECKSUM(NEWID()))*DATEDIFF(dd,'2000','2020')+DATEDIFF(dd,0,'2000') AS DATETIME)
INTO #TestTable
FROM master.sys.all_columns ac1
CROSS JOIN master.sys.all_columns ac2
;
GO

CREATE FUNCTION [dbo].[itvfGetWeekNumberFromDate_ISO_v2]
(
@dDate DATETIME
)
RETURNS @WeekNumber TABLE
(
[Date] DATE NULL
,[DayOfWeek] VARCHAR(20) NULL
,[ISOWeek] INT NULL
)
WITH SCHEMABINDING
AS
BEGIN

/*
SELECT * FROM dbo.itvfGetWeekNumberFromDate_ISO_v2('2009-12-24')
*/

INSERT INTO @WeekNumber
SELECT
CONVERT(VARCHAR(20),@dDate,120) AS [Date]
,LEFT(DATENAME(dw,@dDate),9) AS [DayOfWeek]
,(DATEPART(dy,DATEDIFF(dd,0,@dDate)/7*7+3)+6)/7 AS [ISOWeek]

RETURN

END
GO

CREATE FUNCTION [dbo].[itvfGetWeekNumberFromDate_ISO_v3]
(
@dDate DATETIME
)
RETURNS TABLE
WITH SCHEMABINDING
AS
RETURN SELECT
CONVERT(VARCHAR(20),@dDate,120) AS [Date],
LEFT(DATENAME(dw,@dDate),9) AS [DayOfWeek],
(DATEPART(dy,DATEDIFF(dd,0,@dDate)/7*7+3)+6)/7 AS [ISOWeek];

GO

set nocount on;
--===== Create the timer and bit-bucket variables and start the timer.
DECLARE @BitBucket1 sql_variant,
@BitBucket2 sql_variant,
@BitBucket3 sql_variant; --< change or add variables needed here to eliminate display distortion

Declare @cpu_ int,
@lreads_ bigint,
@eMsec_ bigint,
@Reads_ bigint,
@Writes_ bigint;
declare @CpuMs int,
@LogRds bigint,
@Elapsed bigint,
@Reads bigint,
@Writes bigint;

dbcc freeproccache with no_infomsgs;
dbcc freesystemcache('ALL') with no_infomsgs;
dbcc dropcleanbuffers with no_infomsgs;


Select
@cpu_ = cpu_time
, @lreads_ = logical_reads
, @eMsec_ = total_elapsed_time
, @Reads_ = reads
, @Writes_ = writes
From
sys.dm_exec_requests
Where
session_id = @@spid;

---
SELECT
@BitBucket1 = tvf.Date,
@BitBucket2 = tvf.DayOfWeek,
@BitBucket3 = tvf.ISOWeek
FROM
#TestTable tt
CROSS APPLY
itvfGetWeekNumberFromDate_ISO_v2(tt.Date) tvf
---

Select
@CpuMs = cpu_time - @cpu_
, @LogRds = logical_reads - @lreads_
, @Elapsed = total_elapsed_time - @eMsec_
, @Reads = reads - @Reads_
, @Writes = writes - @Writes_
From
sys.dm_exec_requests
Where
session_id = @@spid;
--===== Display the duration
PRINT 'CPU(ms): ' + right(' ' + cast(@CpuMs as varchar(10)),10) +
' Logical Reads: ' + right(' ' + cast(@LogRds as varchar(10)),10) +
' Elapsed(ms): ' + right(' ' + cast(@Elapsed as varchar(10)),10) +
' Reads: ' + right(' ' + cast(@Reads as varchar(10)),10) +
' Writes: ' + right(' ' + cast(@Writes as varchar(10)),10);

set nocount off;
GO

set nocount on;
--===== Create the timer and bit-bucket variables and start the timer.
DECLARE @BitBucket1 sql_variant,
@BitBucket2 sql_variant,
@BitBucket3 sql_variant; --< change or add variables needed here to eliminate display distortion

Declare @cpu_ int,
@lreads_ bigint,
@eMsec_ bigint,
@Reads_ bigint,
@Writes_ bigint;
declare @CpuMs int,
@LogRds bigint,
@Elapsed bigint,
@Reads bigint,
@Writes bigint;

dbcc freeproccache with no_infomsgs;
dbcc freesystemcache('ALL') with no_infomsgs;
dbcc dropcleanbuffers with no_infomsgs;


Select
@cpu_ = cpu_time
, @lreads_ = logical_reads
, @eMsec_ = total_elapsed_time
, @Reads_ = reads
, @Writes_ = writes
From
sys.dm_exec_requests
Where
session_id = @@spid;

---
SELECT
@BitBucket1 = tvf.Date,
@BitBucket2 = tvf.DayOfWeek,
@BitBucket3 = tvf.ISOWeek
FROM
#TestTable tt
CROSS APPLY
itvfGetWeekNumberFromDate_ISO_v3(tt.Date) tvf
---

Select
@CpuMs = cpu_time - @cpu_
, @LogRds = logical_reads - @lreads_
, @Elapsed = total_elapsed_time - @eMsec_
, @Reads = reads - @Reads_
, @Writes = writes - @Writes_
From
sys.dm_exec_requests
Where
session_id = @@spid;
--===== Display the duration
PRINT 'CPU(ms): ' + right(' ' + cast(@CpuMs as varchar(10)),10) +
' Logical Reads: ' + right(' ' + cast(@LogRds as varchar(10)),10) +
' Elapsed(ms): ' + right(' ' + cast(@Elapsed as varchar(10)),10) +
' Reads: ' + right(' ' + cast(@Reads as varchar(10)),10) +
' Writes: ' + right(' ' + cast(@Writes as varchar(10)),10);

set nocount off;
GO

set nocount on;
--===== Create the timer and bit-bucket variables and start the timer.
DECLARE @BitBucket1 sql_variant,
@BitBucket2 sql_variant,
@BitBucket3 sql_variant; --< change or add variables needed here to eliminate display distortion

Declare @cpu_ int,
@lreads_ bigint,
@eMsec_ bigint,
@Reads_ bigint,
@Writes_ bigint;
declare @CpuMs int,
@LogRds bigint,
@Elapsed bigint,
@Reads bigint,
@Writes bigint;

dbcc freeproccache with no_infomsgs;
dbcc freesystemcache('ALL') with no_infomsgs;
dbcc dropcleanbuffers with no_infomsgs;


Select
@cpu_ = cpu_time
, @lreads_ = logical_reads
, @eMsec_ = total_elapsed_time
, @Reads_ = reads
, @Writes_ = writes
From
sys.dm_exec_requests
Where
session_id = @@spid;

---
SELECT
BitBucket1 = tvf.Date,
BitBucket2 = tvf.DayOfWeek,
BitBucket3 = tvf.ISOWeek
FROM
#TestTable tt
CROSS APPLY
itvfGetWeekNumberFromDate_ISO_v2(tt.Date) tvf
---

Select
@CpuMs = cpu_time - @cpu_
, @LogRds = logical_reads - @lreads_
, @Elapsed = total_elapsed_time - @eMsec_
, @Reads = reads - @Reads_
, @Writes = writes - @Writes_
From
sys.dm_exec_requests
Where
session_id = @@spid;
--===== Display the duration
PRINT 'CPU(ms): ' + right(' ' + cast(@CpuMs as varchar(10)),10) +
' Logical Reads: ' + right(' ' + cast(@LogRds as varchar(10)),10) +
' Elapsed(ms): ' + right(' ' + cast(@Elapsed as varchar(10)),10) +
' Reads: ' + right(' ' + cast(@Reads as varchar(10)),10) +
' Writes: ' + right(' ' + cast(@Writes as varchar(10)),10);

set nocount off;
GO

set nocount on;
--===== Create the timer and bit-bucket variables and start the timer.
DECLARE @BitBucket1 sql_variant,
@BitBucket2 sql_variant,
@BitBucket3 sql_variant; --< change or add variables needed here to eliminate display distortion

Declare @cpu_ int,
@lreads_ bigint,
@eMsec_ bigint,
@Reads_ bigint,
@Writes_ bigint;
declare @CpuMs int,
@LogRds bigint,
@Elapsed bigint,
@Reads bigint,
@Writes bigint;

dbcc freeproccache with no_infomsgs;
dbcc freesystemcache('ALL') with no_infomsgs;
dbcc dropcleanbuffers with no_infomsgs;


Select
@cpu_ = cpu_time
, @lreads_ = logical_reads
, @eMsec_ = total_elapsed_time
, @Reads_ = reads
, @Writes_ = writes
From
sys.dm_exec_requests
Where
session_id = @@spid;

---
SELECT
BitBucket1 = tvf.Date,
BitBucket2 = tvf.DayOfWeek,
BitBucket3 = tvf.ISOWeek
FROM
#TestTable tt
CROSS APPLY
itvfGetWeekNumberFromDate_ISO_v3(tt.Date) tvf
---

Select
@CpuMs = cpu_time - @cpu_
, @LogRds = logical_reads - @lreads_
, @Elapsed = total_elapsed_time - @eMsec_
, @Reads = reads - @Reads_
, @Writes = writes - @Writes_
From
sys.dm_exec_requests
Where
session_id = @@spid;
--===== Display the duration
PRINT 'CPU(ms): ' + right(' ' + cast(@CpuMs as varchar(10)),10) +
' Logical Reads: ' + right(' ' + cast(@LogRds as varchar(10)),10) +
' Elapsed(ms): ' + right(' ' + cast(@Elapsed as varchar(10)),10) +
' Reads: ' + right(' ' + cast(@Reads as varchar(10)),10) +
' Writes: ' + right(' ' + cast(@Writes as varchar(10)),10);

set nocount off;
GO




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)
Alan.B
Alan.B
SSCrazy
SSCrazy (2.2K reputation)SSCrazy (2.2K reputation)SSCrazy (2.2K reputation)SSCrazy (2.2K reputation)SSCrazy (2.2K reputation)SSCrazy (2.2K reputation)SSCrazy (2.2K reputation)SSCrazy (2.2K reputation)

Group: General Forum Members
Points: 2238 Visits: 7424
Wow.

Amazing work Jeff. Great article too. 5 stars.

-- Alan Burstein



Best practices for getting help on SQLServerCentral
Need to split a string? Try DelimitedSplit8K or DelimitedSplit8K_LEAD (SQL 2012+)
Need a pattern-based splitter? Try PatternSplitCM
Need to remove or replace those unwanted characters? Try PatExclude8K and PatReplace8K.

"I can't stress enough the importance of switching from a 'sequential files' mindset to 'set-based' thinking. After you make the switch, you can spend your time tuning and optimizing your queries instead of maintaining lengthy, poor-performing code. " -- Itzek Ben-Gan 2001
Jeff Moden
Jeff Moden
SSC-Forever
SSC-Forever (45K reputation)SSC-Forever (45K reputation)SSC-Forever (45K reputation)SSC-Forever (45K reputation)SSC-Forever (45K reputation)SSC-Forever (45K reputation)SSC-Forever (45K reputation)SSC-Forever (45K reputation)

Group: General Forum Members
Points: 45002 Visits: 39880
Alan.B (4/9/2013)
Wow.

Amazing work Jeff. Great article too. 5 stars.



Thanks, Alan. I really appreciate that.

--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.
Although they tell us that they want it real bad, our primary goal is to ensure that we dont actually give it to them that way.
Although change is inevitable, change for the better is not.
Just because you can do something in PowerShell, doesnt mean you should. Wink

Helpful Links:
How to post code problems
How to post performance problems
Forum FAQs
ALZDBA
ALZDBA
SSCertifiable
SSCertifiable (7K reputation)SSCertifiable (7K reputation)SSCertifiable (7K reputation)SSCertifiable (7K reputation)SSCertifiable (7K reputation)SSCertifiable (7K reputation)SSCertifiable (7K reputation)SSCertifiable (7K reputation)

Group: General Forum Members
Points: 6972 Visits: 8839
Lynn Pettis (4/9/2013)
Create an empty database and run the following:
...


Tested your script at my slow box:

CPU(ms):     102009 Logical Reads:   10002259 Elapsed(ms):     104478 Reads:       2044 Writes:          0
CPU(ms): 2745 Logical Reads: 2175 Elapsed(ms): 2867 Reads: 2016 Writes: 0
CPU(ms): 100028 Logical Reads: 10002257 Elapsed(ms): 101861 Reads: 2043 Writes: 0
CPU(ms): 2090 Logical Reads: 2175 Elapsed(ms): 11723 Reads: 2016 Writes: 0
[

Clear case with regards to the conclusion for the test Cool

Lovely script on how easy one can just measure such consumption.

Johan


Don't drive faster than your guardian angel can fly ...
but keeping both feet on the ground won't get you anywhere w00t

- How to post Performance Problems
- How to post data/code to get the best help


- How to prevent a sore throat after hours of presenting ppt ?


"press F1 for solution", "press shift+F1 for urgent solution" :-D


Need a bit of Powershell? How about this

Who am I ? Sometimes this is me Alien but most of the time this is me Hehe
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