The maximum recursion 100 has been exhausted before statement completion

  • 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.

    [/code]

    thanks in advance.

    ___
    Known Is An Drop,Unknown Is An Ocean....
    Njoy Programming
    🙂

  • 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

    Author of:
    SQL Server Execution Plans
    SQL Server Query Performance Tuning

  • 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.

  • 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')

  • Apologies I posted a slightly incorrect query, given your requirements. It should have:

    COUNT(*)

    in place of the:

    DATENAME(dw,date)

  • 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

  • Jonathan,

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

  • @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"

  • Thanks Grant Fritchey & kruti, i Got the solution from your guidance

    once again thanks

    ___
    Known Is An Drop,Unknown Is An Ocean....
    Njoy Programming
    🙂

  • 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.

  • A while back, Jeff Modem came up with this cute one:

    create function workdays_jeff(@p_startdate datetime, @p_enddate datetime) returns integer as

    begin

    return

    (DATEDIFF(dd, @p_startdate, @p_enddate)+1)

    -(DATEDIFF(wk, @p_startdate, @p_enddate) * 2)

    -(CASE WHEN DATENAME(dw, @p_startdate) = 'Sunday' THEN 1 ELSE 0 END)

    -(CASE WHEN DATENAME(dw, @p_enddate) = 'Saturday' THEN 1 ELSE 0 END)

    end

  • nigel (9/2/2009)


    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.

    I concur. I wasn't addressing the overall performance, just how to get around the immediate issue.

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

    Author of:
    SQL Server Execution Plans
    SQL Server Query Performance Tuning

  • Michael Meierruth (9/2/2009)


    A while back, Jeff Modem came up with this cute one:

    Michael,

    I'd completely forgotten about that little gem. Well remembered.

  • Hi Grasshopper,

    Just stumbled on your topic and thought about why one should limit oneself with maximum recursion limit? We can use even less memory if we want to... The only price for this is just a longer query execution period. So it's up to you what approach to use.

    In fact we can generate as many records as we want without affecting that limit value and writing a stored procedure. We just need to reuse your initial approach several times using Cartesian Join... Lets say we want to count weekdays in several years period. Joining your DateList virtual table (which mast not exceed 100 rows ) for three times in Cartesian join we get third power of hundred which is a million rows record set. The more we join the more we get (use reasonable amount of joins;-) )

    Here the solution:

    DECLARE @STARTDATE datetime;

    DECLARE @EntDt datetime;

    set @STARTDATE = '01/01/2009';

    set @EntDt = '12/31/2009';

    WITH

    hierarchy (level) as

    (

    select 0 level

    union all

    select h.level + 1

    from hierarchy h

    where h.level < 100

    ),

    LotsOfRows(rownumber) as

    (

    select cast(@STARTDATE as datetime) + ROW_NUMBER() over (order by rand() /*h1.level*/) as rownumber --with Rand() it works a way faster

    from hierarchy h1

    ,hierarchy h2

    ,hierarchy h3

    )

    select count(*) as DayCnt from (

    select rownumber, DATENAME(WEEKDAY, rownumber ) as WEEKDAY

    from LotsOfRows

    where DATENAME(WEEKDAY, rownumber ) not IN ( 'Saturday','Sunday' )

    and rownumber < convert(VARCHAR(15),@EntDt,101)

    )a

    In fact that's not my solution 😉 I spied it on from an Oracle guy who does the same using famous connect by approach.

    http://blog.tanelpoder.com/2008/06/08/generating-lots-of-rows-using-connect-by-safely/

  • Use this Statement

    OPTION (MAXRECURSION 0)

Viewing 15 posts - 1 through 15 (of 18 total)

You must be logged in to reply to this topic. Login to reply