SQL Clone
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


Working of the function


Working of the function

Author
Message
VSSGeorge
VSSGeorge
SSCrazy
SSCrazy (2.1K reputation)SSCrazy (2.1K reputation)SSCrazy (2.1K reputation)SSCrazy (2.1K reputation)SSCrazy (2.1K reputation)SSCrazy (2.1K reputation)SSCrazy (2.1K reputation)SSCrazy (2.1K reputation)

Group: General Forum Members
Points: 2053 Visits: 1578
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



twin.devil
twin.devil
SSCertifiable
SSCertifiable (5.1K reputation)SSCertifiable (5.1K reputation)SSCertifiable (5.1K reputation)SSCertifiable (5.1K reputation)SSCertifiable (5.1K reputation)SSCertifiable (5.1K reputation)SSCertifiable (5.1K reputation)SSCertifiable (5.1K reputation)

Group: General Forum Members
Points: 5086 Visits: 2692
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/
ChrisM@Work
ChrisM@Work
SSC-Dedicated
SSC-Dedicated (39K reputation)SSC-Dedicated (39K reputation)SSC-Dedicated (39K reputation)SSC-Dedicated (39K reputation)SSC-Dedicated (39K reputation)SSC-Dedicated (39K reputation)SSC-Dedicated (39K reputation)SSC-Dedicated (39K reputation)

Group: General Forum Members
Points: 39082 Visits: 19989
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
ChrisM@Work
ChrisM@Work
SSC-Dedicated
SSC-Dedicated (39K reputation)SSC-Dedicated (39K reputation)SSC-Dedicated (39K reputation)SSC-Dedicated (39K reputation)SSC-Dedicated (39K reputation)SSC-Dedicated (39K reputation)SSC-Dedicated (39K reputation)SSC-Dedicated (39K reputation)

Group: General Forum Members
Points: 39082 Visits: 19989
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
Jeff Moden
Jeff Moden
SSC Guru
SSC Guru (202K reputation)SSC Guru (202K reputation)SSC Guru (202K reputation)SSC Guru (202K reputation)SSC Guru (202K reputation)SSC Guru (202K reputation)SSC Guru (202K reputation)SSC Guru (202K reputation)

Group: General Forum Members
Points: 202775 Visits: 41943
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.
If you think its expensive to hire a professional to do the job, wait until you hire an amateur. -- Red Adair

Helpful Links:
How to post code problems
How to post performance problems
Forum FAQs
ChrisM@Work
ChrisM@Work
SSC-Dedicated
SSC-Dedicated (39K reputation)SSC-Dedicated (39K reputation)SSC-Dedicated (39K reputation)SSC-Dedicated (39K reputation)SSC-Dedicated (39K reputation)SSC-Dedicated (39K reputation)SSC-Dedicated (39K reputation)SSC-Dedicated (39K reputation)

Group: General Forum Members
Points: 39082 Visits: 19989
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
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