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

Working of the function Expand / Collapse
Author
Message
Posted Friday, November 29, 2013 6:08 AM


SSChasing Mays

SSChasing MaysSSChasing MaysSSChasing MaysSSChasing MaysSSChasing MaysSSChasing MaysSSChasing MaysSSChasing Mays

Group: General Forum Members
Last Login: Wednesday, November 5, 2014 4:54 AM
Points: 611, Visits: 1,149
I have an existing function on my DB which is used for date manipulations.
Please explain how this function works.

ALTER FUNCTION [dbo].[ExplodeDates](@startdate datetime, @enddate datetime)
returns table as
return (
with
N0 as (SELECT 1 as n UNION ALL SELECT 1)
,N1 as (SELECT 1 as n FROM N0 t1, N0 t2)
,N2 as (SELECT 1 as n FROM N1 t1, N1 t2)
,N3 as (SELECT 1 as n FROM N2 t1, N2 t2)
,N4 as (SELECT 1 as n FROM N3 t1, N3 t2)
,N5 as (SELECT 1 as n FROM N4 t1, N4 t2)
,N6 as (SELECT 1 as n FROM N5 t1, N5 t2)
,nums as (SELECT ROW_NUMBER() OVER (ORDER BY (SELECT 1)) as num FROM N6)
SELECT DATEADD(day,num-1,@startdate) as thedate
FROM nums
WHERE num <= DATEDIFF(day,@startdate,@enddate) + 1


Post #1518531
Posted Friday, November 29, 2013 6:21 AM
SSC Eights!

SSC Eights!SSC Eights!SSC Eights!SSC Eights!SSC Eights!SSC Eights!SSC Eights!SSC Eights!

Group: General Forum Members
Last Login: Today @ 12:32 AM
Points: 829, Visits: 1,469
This function is using Tally Table approach to generate calendar date between the @startDate And @EndDate

if you want to understand properly then using this post from Stefan Krzywicki "Tally Table Uses - Part I" http://www.sqlservercentral.com/articles/Tally+Table/70735/



Post #1518535
Posted Friday, November 29, 2013 7:07 AM


SSCertifiable

SSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiable

Group: General Forum Members
Last Login: Yesterday @ 9:40 AM
Points: 6,864, Visits: 14,165
Run the following code, query by query. If you're still unsure, post back.
WITH 
N0 as (SELECT 1 as n UNION ALL SELECT 1) -- 2 rows
,N1 as (SELECT 1 as n FROM N0 t1, N0 t2) -- 4 rows
SELECT * FROM N1;

WITH
N0 as (SELECT 1 as n UNION ALL SELECT 1) -- 2 rows
,N1 as (SELECT 1 as n FROM N0 t1, N0 t2) -- 4 rows
SELECT ROW_NUMBER() OVER (ORDER BY (SELECT NULL)) as num FROM N1;

WITH
N0 as (SELECT 1 as n UNION ALL SELECT 1) -- 2 rows
,N1 as (SELECT 1 as n FROM N0 t1, N0 t2) -- 4 rows
,nums AS (SELECT ROW_NUMBER() OVER (ORDER BY (SELECT NULL)) as num FROM N1)
SELECT DATEADD(day,num, GETDATE()) FROM nums;



“Write the query the simplest way. If through testing it becomes clear that the performance is inadequate, consider alternative query forms.” - Gail Shaw

For fast, accurate and documented assistance in answering your questions, please read this article.
Understanding and using APPLY, (I) and (II) Paul White
Hidden RBAR: Triangular Joins / The "Numbers" or "Tally" Table: What it is and how it replaces a loop Jeff Moden
Exploring Recursive CTEs by Example Dwain Camps
Post #1518548
Posted Friday, November 29, 2013 7:09 AM


SSCertifiable

SSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiable

Group: General Forum Members
Last Login: Yesterday @ 9:40 AM
Points: 6,864, Visits: 14,165
Note that you don't need CTE N6:
DECLARE @startdate DATE, @enddate DATE
SET @startdate = '00010101'
SET @enddate = '99990101';

with
N0 as (SELECT 1 as n UNION ALL SELECT 1) -- 2 rows
,N1 as (SELECT 1 as n FROM N0 t1, N0 t2) -- 4 rows
,N2 as (SELECT 1 as n FROM N1 t1, N1 t2) -- 16 rows
,N3 as (SELECT 1 as n FROM N2 t1, N2 t2) -- 256 rows
,N4 as (SELECT 1 as n FROM N3 t1, N3 t2) -- 65,536 rows
,N5 as (SELECT 1 as n FROM N4 t1, N4 t2) -- 4,294,967,296 rows
--,N6 as (SELECT 1 as n FROM N5 t1, N5 t2) -- 18,446,744,073,709,551,616 rows!!
,nums as (SELECT ROW_NUMBER() OVER (ORDER BY (SELECT 1)) as num FROM N5)
SELECT DATEADD(day,num-1,@startdate) as thedate
FROM nums
WHERE num <= DATEDIFF(day, @startdate, @enddate) + 1



“Write the query the simplest way. If through testing it becomes clear that the performance is inadequate, consider alternative query forms.” - Gail Shaw

For fast, accurate and documented assistance in answering your questions, please read this article.
Understanding and using APPLY, (I) and (II) Paul White
Hidden RBAR: Triangular Joins / The "Numbers" or "Tally" Table: What it is and how it replaces a loop Jeff Moden
Exploring Recursive CTEs by Example Dwain Camps
Post #1518550
Posted Friday, November 29, 2013 2:05 PM


SSC-Dedicated

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

Group: General Forum Members
Last Login: Yesterday @ 11:32 PM
Points: 35,584, Visits: 32,174
Not that many people would notice but you can get the code to be almost a third faster by eliminating the (-1) subtraction. Last but not least, the simplification actually instills a guarantee that you won't have an accidental overrun sometimes caused by the very rare but annoying delay as to when the WHERE clause is executed when you join the results of this function in an external query (Itzik Ben-Gan published that correction to his code just a couple of days after he first published the cascading CTE method used here).
 CREATE FUNCTION dbo.ExplodeDates
(
@pStartDate DATETIME
,@pEndDate DATETIME
)
RETURNS TABLE WITH SCHEMABINDING AS
RETURN WITH
E1(N) AS (
SELECT 1 UNION ALL SELECT 1 UNION ALL
SELECT 1 UNION ALL SELECT 1 UNION ALL
SELECT 1 UNION ALL SELECT 1 UNION ALL
SELECT 1 UNION ALL SELECT 1 UNION ALL
SELECT 1 UNION ALL SELECT 1
)
, E7(N) AS (SELECT 1 FROM E1 a, E1 b, E1 c, E1 d, E1 e, E1 f, E1 g)
SELECT TheDate = @pStartDate UNION ALL --This eliminates the need for subtraction on the Row_Number
SELECT TOP (DATEDIFF(dd,@pStartDate,@pEndDate)) --and addition here
TheDate = DATEADD(dd,ROW_NUMBER() OVER (ORDER BY (SELECT NULL)),@pStartDate)
FROM E7
;



--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 #1518596
Posted Monday, December 2, 2013 2:57 AM


SSCertifiable

SSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiable

Group: General Forum Members
Last Login: Yesterday @ 9:40 AM
Points: 6,864, Visits: 14,165
Jeff Moden (11/29/2013)
Not that many people would notice but you can get the code to be almost a third faster by eliminating the (-1) subtraction. Last but not least, the simplification actually instills a guarantee that you won't have an accidental overrun sometimes caused by the very rare but annoying delay as to when the WHERE clause is executed when you join the results of this function in an external query (Itzik Ben-Gan published that correction to his code just a couple of days after he first published the cascading CTE method used here).
 CREATE FUNCTION dbo.ExplodeDates
(
@pStartDate DATETIME
,@pEndDate DATETIME
)
RETURNS TABLE WITH SCHEMABINDING AS
RETURN WITH
E1(N) AS (
SELECT 1 UNION ALL SELECT 1 UNION ALL
SELECT 1 UNION ALL SELECT 1 UNION ALL
SELECT 1 UNION ALL SELECT 1 UNION ALL
SELECT 1 UNION ALL SELECT 1 UNION ALL
SELECT 1 UNION ALL SELECT 1
)
, E7(N) AS (SELECT 1 FROM E1 a, E1 b, E1 c, E1 d, E1 e, E1 f, E1 g)
SELECT TheDate = @pStartDate UNION ALL --This eliminates the need for subtraction on the Row_Number
SELECT TOP (DATEDIFF(dd,@pStartDate,@pEndDate)) --and addition here
TheDate = DATEADD(dd,ROW_NUMBER() OVER (ORDER BY (SELECT NULL)),@pStartDate)
FROM E7
;



How are you demonstrating the difference, Jeff? The results of a quick test show the opposite, but not by very much:
DECLARE @startdate DATE, @enddate DATE, @Blackhole DATE;
SET @startdate = '00010101'
SET @enddate = '99991231';



PRINT '==Slow inline tally table==';

PRINT CHAR(10)+'--Subtraction--';
SET STATISTICS TIME ON;
with
N0 as (SELECT 1 as n UNION ALL SELECT 1) -- 2 rows
,N1 as (SELECT 1 as n FROM N0 t1, N0 t2) -- 4 rows
,N2 as (SELECT 1 as n FROM N1 t1, N1 t2) -- 16 rows
,N3 as (SELECT 1 as n FROM N2 t1, N2 t2) -- 256 rows
,N4 as (SELECT 1 as n FROM N3 t1, N3 t2) -- 65,536 rows
,N5 as (SELECT 1 as n FROM N4 t1, N4 t2) -- 4,294,967,296 rows
,nums as (SELECT ROW_NUMBER() OVER (ORDER BY (SELECT 1)) as num FROM N5)
SELECT @Blackhole = thedate FROM (
SELECT thedate = DATEADD(day,num-1,@startdate)
FROM nums
WHERE num <= DATEDIFF(day, @startdate, @enddate) + 1
) d;
SET STATISTICS TIME OFF;

PRINT CHAR(10)+'--UNION--';
SET STATISTICS TIME ON;
with
N0 as (SELECT 1 as n UNION ALL SELECT 1) -- 2 rows
,N1 as (SELECT 1 as n FROM N0 t1, N0 t2) -- 4 rows
,N2 as (SELECT 1 as n FROM N1 t1, N1 t2) -- 16 rows
,N3 as (SELECT 1 as n FROM N2 t1, N2 t2) -- 256 rows
,N4 as (SELECT 1 as n FROM N3 t1, N3 t2) -- 65,536 rows
,N5 as (SELECT 1 as n FROM N4 t1, N4 t2) -- 4,294,967,296 rows
,nums as (SELECT ROW_NUMBER() OVER (ORDER BY (SELECT 1)) as num FROM N5)
SELECT @Blackhole = thedate FROM (
SELECT thedate = @startdate
UNION ALL
SELECT DATEADD(day,num,@startdate)
FROM nums
WHERE num <= DATEDIFF(day, @startdate, @enddate)
) d;
SET STATISTICS TIME OFF;




PRINT CHAR(10)+CHAR(10)+'==Fast IBG inline tally table==';

PRINT CHAR(10)+'--Subtraction--';
SET STATISTICS TIME ON;
WITH
E1(N) AS (
SELECT 1 UNION ALL SELECT 1 UNION ALL
SELECT 1 UNION ALL SELECT 1 UNION ALL
SELECT 1 UNION ALL SELECT 1 UNION ALL
SELECT 1 UNION ALL SELECT 1 UNION ALL
SELECT 1 UNION ALL SELECT 1
)
, E7(N) AS (SELECT 1 FROM E1 a, E1 b, E1 c, E1 d, E1 e, E1 f, E1 g)

SELECT @Blackhole = thedate FROM (
SELECT TOP (1+DATEDIFF(dd,@StartDate,@EndDate))
TheDate = DATEADD(dd,ROW_NUMBER() OVER (ORDER BY (SELECT NULL))-1,@StartDate)
FROM E7
) d;
SET STATISTICS TIME OFF;

PRINT CHAR(10)+'--UNION--';
SET STATISTICS TIME ON;
WITH
E1(N) AS (
SELECT 1 UNION ALL SELECT 1 UNION ALL
SELECT 1 UNION ALL SELECT 1 UNION ALL
SELECT 1 UNION ALL SELECT 1 UNION ALL
SELECT 1 UNION ALL SELECT 1 UNION ALL
SELECT 1 UNION ALL SELECT 1
)
, E7(N) AS (SELECT 1 FROM E1 a, E1 b, E1 c, E1 d, E1 e, E1 f, E1 g)
SELECT @Blackhole = thedate FROM (
SELECT TheDate = @StartDate
UNION ALL --This eliminates the need for subtraction on the Row_Number
SELECT TOP (DATEDIFF(dd,@StartDate,@EndDate)) --and addition here
TheDate = DATEADD(dd,ROW_NUMBER() OVER (ORDER BY (SELECT NULL)),@StartDate)
FROM E7
) d
;
SET STATISTICS TIME OFF;
PRINT '=================================================================================';



“Write the query the simplest way. If through testing it becomes clear that the performance is inadequate, consider alternative query forms.” - Gail Shaw

For fast, accurate and documented assistance in answering your questions, please read this article.
Understanding and using APPLY, (I) and (II) Paul White
Hidden RBAR: Triangular Joins / The "Numbers" or "Tally" Table: What it is and how it replaces a loop Jeff Moden
Exploring Recursive CTEs by Example Dwain Camps
Post #1518809
« Prev Topic | Next Topic »

Add to briefcase

Permissions Expand / Collapse