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


The maximum recursion 100 has been exhausted before statement completion


The maximum recursion 100 has been exhausted before statement completion

Author
Message
windows_mss
windows_mss
Valued Member
Valued Member (70 reputation)Valued Member (70 reputation)Valued Member (70 reputation)Valued Member (70 reputation)Valued Member (70 reputation)Valued Member (70 reputation)Valued Member (70 reputation)Valued Member (70 reputation)

Group: General Forum Members
Points: 70 Visits: 180
Dear Expert,

I want to find the number of Working days in a year,

so i passed the two date values to startdate and enddates respectively,

When i giving input as

set @STARTDATE = '01/01/2009';
set @EntDt = '03/31/2009';

i'm getting result as 63 it's fine, but when i give End date as '12/31/2009'; getting the following error

The statement terminated. The maximum recursion 100 has been exhausted before statement completion.

i had attached my code with this post,

guidance needed


DECLARE @STARTDATE datetime;
DECLARE @EntDt datetime;
set @STARTDATE = '01/01/2009';
set @EntDt = '12/31/2009';
declare @dcnt int;
;with DateList as
(
select cast(@STARTDATE as datetime) DateValue
union all
select DateValue + 1 from DateList
where DateValue + 1 < convert(VARCHAR(15),@EntDt,101)
)

select count(*) as DayCnt from (
select DateValue,DATENAME(WEEKDAY, DateValue ) as WEEKDAY from DateList
where DATENAME(WEEKDAY, DateValue ) not IN ( 'Saturday','Sunday' )
)a


Msg 530, Level 16, State 1, Line 6
The statement terminated. The maximum recursion 100 has been exhausted before statement completion.




thanks in advance.

___
Known Is An Drop,Unknown Is An Ocean....
Njoy Programming
:-)
Grant Fritchey
Grant Fritchey
SSC-Insane
SSC-Insane (20K reputation)SSC-Insane (20K reputation)SSC-Insane (20K reputation)SSC-Insane (20K reputation)SSC-Insane (20K reputation)SSC-Insane (20K reputation)SSC-Insane (20K reputation)SSC-Insane (20K reputation)

Group: General Forum Members
Points: 20295 Visits: 32375
Maybe not the greatest approach to the solution, but you could just add WITH MAXRECURSION = 365 query hint. Recursion is limited to ~32,000 calls.

----------------------------------------------------
The credit belongs to the man who is actually in the arena, whose face is marred by dust and sweat and blood...
Theodore Roosevelt

The Scary DBA
Author of: SQL Server Query Performance Tuning and SQL Server Execution Plans
Product Evangelist for Red Gate Software
nigel.
nigel.
UDP Broadcaster
UDP Broadcaster (1.5K reputation)UDP Broadcaster (1.5K reputation)UDP Broadcaster (1.5K reputation)UDP Broadcaster (1.5K reputation)UDP Broadcaster (1.5K reputation)UDP Broadcaster (1.5K reputation)UDP Broadcaster (1.5K reputation)UDP Broadcaster (1.5K reputation)

Group: General Forum Members
Points: 1495 Visits: 2825
Here's an alternative that doesn't use a recursive CTE to generate the dates.

DECLARE @d1 datetime, @d2 datetime
DECLARE @n int

SELECT
@d1 = '20090831',
@d2 = '20090904',
@n = DATEDIFF(day,@d1,@d2)

SELECT
DATENAME(dw,date)
FROM
(
SELECT TOP (@n)
date = DATEADD( day,
ROW_NUMBER()OVER (ORDER BY t1.name)-1,
@d1)
FROM
sys.columns t1, sys.columns t2
) d
WHERE
DATENAME(dw,date) NOT IN ('Saturday','Sunday')



I notice that your solution excludes the end date (@EndDt) in the count, is that intentional?
The above solution does the same. If you need to include the end date change the line:
        @n = DATEDIFF(day,@d1,@d2)


to
        @n = DATEDIFF(day,@d1,@d2)+1


Alternative solutions could use either a Tally or Calendar table.

--
Nigel
Useful Links:
How to post data/code on a forum to get the best help
The "Numbers" or "Tally" Table - Jeff Moden

Jonathan Mallia
Jonathan Mallia
Ten Centuries
Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)

Group: General Forum Members
Points: 1091 Visits: 1288
To add on Nigel's post, you enhance the query in the following way:


DECLARE @d1 datetime, @d2 datetime
DECLARE @n int

SELECT
@d1 = '20090831',
@d2 = '20090930',
@n = DATEDIFF(day,@d1,@d2)

SELECT
CAST(DATENAME(dw,date) AS Nvarchar(15)) + ', ' + CASE RIGHT(CAST(DATEPART(dd, date) AS Nvarchar(2)), 1)
WHEN 1 THEN CAST(DATEPART(dd, date) AS Nvarchar(2)) + 'st'
WHEN 2 THEN CAST(DATEPART(dd, date) AS Nvarchar(2)) + 'nd'
WHEN 3 THEN CAST(DATEPART(dd, date) AS Nvarchar(2)) + 'rd'
ELSE
CAST(DATEPART(dd, date) AS Nvarchar(2)) + 'th'
END
FROM
(
SELECT TOP (@n)
date = DATEADD( day,
ROW_NUMBER()OVER (ORDER BY t1.name)-1,
@d1)
FROM
sys.columns t1, sys.columns t2
) d
WHERE DATENAME(dw,date) NOT IN ('Saturday','Sunday')



nigel.
nigel.
UDP Broadcaster
UDP Broadcaster (1.5K reputation)UDP Broadcaster (1.5K reputation)UDP Broadcaster (1.5K reputation)UDP Broadcaster (1.5K reputation)UDP Broadcaster (1.5K reputation)UDP Broadcaster (1.5K reputation)UDP Broadcaster (1.5K reputation)UDP Broadcaster (1.5K reputation)

Group: General Forum Members
Points: 1495 Visits: 2825
Apologies I posted a slightly incorrect query, given your requirements. It should have:

       COUNT(*)



in place of the:

       DATENAME(dw,date)



--
Nigel
Useful Links:
How to post data/code on a forum to get the best help
The "Numbers" or "Tally" Table - Jeff Moden

nigel.
nigel.
UDP Broadcaster
UDP Broadcaster (1.5K reputation)UDP Broadcaster (1.5K reputation)UDP Broadcaster (1.5K reputation)UDP Broadcaster (1.5K reputation)UDP Broadcaster (1.5K reputation)UDP Broadcaster (1.5K reputation)UDP Broadcaster (1.5K reputation)UDP Broadcaster (1.5K reputation)

Group: General Forum Members
Points: 1495 Visits: 2825
Have been pondering this and have come up with an alternative that uses a Tally table:

DECLARE @d1 datetime, @d2 datetime

SELECT
@d1 = '20090101',
@d2 = '20090331'

SELECT
count(N)
FROM
Tally
WHERE
N <= DATEDIFF(day,@d1,@d2)+1
AND
(DATEPART(dw,DATEADD(dd,n-1,@d1))+@@DATEFIRST)%7 BETWEEN 2 AND 6





Advantages over previous solutions, as I see it, are:
- Doesn't use CTE's (recursive or otherwise) or ROW_NUMBER, so can be used in SQL 2000.
- The query itself is a lot simpler to read
- Looking at the query plan 92% of the time is spent doing a clustered index seek.
- Use of @@DATEFIRST and Modulus operator makes the solution multi-culture
- Use of BETWEEN rather than NOT IN is significantly quicker

--
Nigel
Useful Links:
How to post data/code on a forum to get the best help
The "Numbers" or "Tally" Table - Jeff Moden

nigel.
nigel.
UDP Broadcaster
UDP Broadcaster (1.5K reputation)UDP Broadcaster (1.5K reputation)UDP Broadcaster (1.5K reputation)UDP Broadcaster (1.5K reputation)UDP Broadcaster (1.5K reputation)UDP Broadcaster (1.5K reputation)UDP Broadcaster (1.5K reputation)UDP Broadcaster (1.5K reputation)

Group: General Forum Members
Points: 1495 Visits: 2825
Jonathan,

Minor problem, your query doesn't get the 11th, 12th and 13th correct, you get 11st, 12nd and 13rd instead. Oops! :-)

--
Nigel
Useful Links:
How to post data/code on a forum to get the best help
The "Numbers" or "Tally" Table - Jeff Moden

Kruti Kansara
Kruti Kansara
Mr or Mrs. 500
Mr or Mrs. 500 (556 reputation)Mr or Mrs. 500 (556 reputation)Mr or Mrs. 500 (556 reputation)Mr or Mrs. 500 (556 reputation)Mr or Mrs. 500 (556 reputation)Mr or Mrs. 500 (556 reputation)Mr or Mrs. 500 (556 reputation)Mr or Mrs. 500 (556 reputation)

Group: General Forum Members
Points: 556 Visits: 412
@Grant Fritchey

Yes u r right!

it just need to add 'Option (maxrecursion 365)' (100 is the default limit for CTE, one can set it upto 32767 with 'maxrecursion')

DECLARE @STARTDATE datetime; 
DECLARE @EntDt datetime;
set @STARTDATE = '01/01/2009';
set @EntDt = '12/31/2009';
declare @dcnt int;
;with DateList as
(
select @STARTDATE DateValue
union all
select DateValue + 1 from DateList
where DateValue + 1 < convert(VARCHAR(15),@EntDt,101)
)
select count(*) as DayCnt from (
select DateValue,DATENAME(WEEKDAY, DateValue ) as WEEKDAY from DateList
where DATENAME(WEEKDAY, DateValue ) not IN ( 'Saturday','Sunday' )
)a
option (maxrecursion 365);



"Don't limit your challenges, challenge your limits"
windows_mss
windows_mss
Valued Member
Valued Member (70 reputation)Valued Member (70 reputation)Valued Member (70 reputation)Valued Member (70 reputation)Valued Member (70 reputation)Valued Member (70 reputation)Valued Member (70 reputation)Valued Member (70 reputation)

Group: General Forum Members
Points: 70 Visits: 180
Thanks Grant Fritchey & kruti, i Got the solution from your guidance

once again thanks

___
Known Is An Drop,Unknown Is An Ocean....
Njoy Programming
:-)
nigel.
nigel.
UDP Broadcaster
UDP Broadcaster (1.5K reputation)UDP Broadcaster (1.5K reputation)UDP Broadcaster (1.5K reputation)UDP Broadcaster (1.5K reputation)UDP Broadcaster (1.5K reputation)UDP Broadcaster (1.5K reputation)UDP Broadcaster (1.5K reputation)UDP Broadcaster (1.5K reputation)

Group: General Forum Members
Points: 1495 Visits: 2825
Sure, setting MAXRECUSRION will work, but at what expense?
Grant even said in his post that it wasn't the greatest approach.
I would avoid recursive CTEs if there is a more efficient solution, which in this case there is.

--
Nigel
Useful Links:
How to post data/code on a forum to get the best help
The "Numbers" or "Tally" Table - Jeff Moden

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