CTE Performance

  • The purpose of the "inlcuded columns" in the index is to remove the key lookup. In the test4 of the article, it achieved this by removing those columns (GroupName, ParentGroupName,ParentGroupID) in the recursive part. Though CTE method performance improved a lot, you can see the results were still favour to the Loop method.

    I tested the way to eliminate the key lookup by creating inlcuded columns in the table as recommended by Newbie (thanks). On my server (which is different from that the original tests were taken), the results showed CTE can benifit more than the Loop from the new index and the performance is close to Loop, but it's still shy of it:

    Test 2: Two roots, three children under a node, 10 levels

    -- 1) @GroupID=3, 9841 rows, 9 levels

    By CTE: Starts at 2007-05-10 09:30:23.563, Finishes at 2007-05-10 09:30:24.597, Takes 1033ms

    By Loop: Starts at 2007-05-10 09:30:53.237, Finishes at 2007-05-10 09:30:53.953, Takes 716ms

    By CTE: Starts at 2007-05-10 09:31:37.253, Finishes at 2007-05-10 09:31:38.207, Takes 953ms

    By Loop: Starts at 2007-05-10 09:31:53.393, Finishes at 2007-05-10 09:31:54.127, Takes 733ms

     

  • I found the exact opposite on my dev enviornment.  The CTE procs out performed the loop procedures.  I used the scripts and ran through all the test scenarios and found the CTE ran 50% faster than the loop.  I'm running Windows 2003 Enterprise Edition, SQL 2005 Enterprise Edition SP2, 4 Dual Core (3.0 GHZ) Processors and 2 GB RAM. 

     

    I also use Recursive CTEs in a real production environment (3.2 TB Database) on 200 million and almost Billion row tables with a hierachly data structure and many nodes.  I've never had an issue with CTE performance as long as indexes are tuned properly.  I would not shy away from using CTE just because of this article. 

     

  • That's odd. I've tested CTEs vs loops on hierarchy data and ended up with slightly better performance in the CTE than the loop. Directly contradicts what you ended up with.

    set statistics io on

    set statistics time on

    declare @TopStructureID_in int

    select @topstructureid_in =

    (select structureid

    from dbo.campaigns

    where campaignid = 560)

    declare @Hierarchy table (

    Lvl int not null,

    StructureID int not null,

    ParentID int,

    primary key (lvl, structureid),

    State varchar(3))

    declare @Rows int

    insert into @hierarchy (lvl, structureid, parentid, state)

    select 1, structureid, parentstructureid, rowstate

    from dbo.corporatestructure

    where structureid = @topstructureid_in

    and rowstate != 'del'

    select @rows = @@rowcount

    while @rows > 0

    begin

    insert into @hierarchy (lvl, structureid, parentid, state)

    select 1 + h2.lvl,

    c2.structureid, c2.parentstructureid, c2.RowState

    from dbo.corporatestructure c2

    inner join @hierarchy h2

    on c2.parentstructureid = h2.structureid

    where c2.rowstate != 'del'

    and c2.structureid not in

    (select structureid

    from @hierarchy)

    select @rows = @@rowcount

    end

    select *

    from @hierarchy

    ==============================

    Table 'Campaigns'. Scan count 0, logical reads 2, physical reads 0, read-ahead reads 0, lob logical reads 0, lob physical reads 0, lob read-ahead reads 0.

    SQL Server Execution Times:

    CPU time = 0 ms, elapsed time = 1 ms.

    Table '#131B4459'. Scan count 0, logical reads 3, physical reads 0, read-ahead reads 0, lob logical reads 0, lob physical reads 0, lob read-ahead reads 0.

    Table 'CorporateStructure'. Scan count 0, logical reads 2, physical reads 0, read-ahead reads 0, lob logical reads 0, lob physical reads 0, lob read-ahead reads 0.

    SQL Server Execution Times:

    CPU time = 0 ms, elapsed time = 1 ms.

    (1 row(s) affected)

    SQL Server Execution Times:

    CPU time = 0 ms, elapsed time = 1 ms.

    SQL Server Execution Times:

    CPU time = 0 ms, elapsed time = 1 ms.

    Table '#131B4459'. Scan count 2, logical reads 71, physical reads 0, read-ahead reads 0, lob logical reads 0, lob physical reads 0, lob read-ahead reads 0.

    Table 'Worktable'. Scan count 1, logical reads 37, physical reads 0, read-ahead reads 0, lob logical reads 0, lob physical reads 0, lob read-ahead reads 0.

    Table 'CorporateStructure'. Scan count 1, logical reads 2, physical reads 0, read-ahead reads 0, lob logical reads 0, lob physical reads 0, lob read-ahead reads 0.

    SQL Server Execution Times:

    CPU time = 15 ms, elapsed time = 1 ms.

    (17 row(s) affected)

    SQL Server Execution Times:

    CPU time = 0 ms, elapsed time = 1 ms.

    SQL Server Execution Times:

    CPU time = 0 ms, elapsed time = 1 ms.

    Table '#131B4459'. Scan count 2, logical reads 381, physical reads 0, read-ahead reads 0, lob logical reads 0, lob physical reads 0, lob read-ahead reads 0.

    Table 'Worktable'. Scan count 1, logical reads 174, physical reads 0, read-ahead reads 0, lob logical reads 0, lob physical reads 0, lob read-ahead reads 0.

    Table 'CorporateStructure'. Scan count 18, logical reads 36, physical reads 0, read-ahead reads 0, lob logical reads 0, lob physical reads 0, lob read-ahead reads 0.

    SQL Server Execution Times:

    CPU time = 0 ms, elapsed time = 3 ms.

    (86 row(s) affected)

    SQL Server Execution Times:

    CPU time = 0 ms, elapsed time = 1 ms.

    SQL Server Execution Times:

    CPU time = 0 ms, elapsed time = 1 ms.

    Table '#131B4459'. Scan count 2, logical reads 729, physical reads 0, read-ahead reads 0, lob logical reads 0, lob physical reads 0, lob read-ahead reads 0.

    Table 'Worktable'. Scan count 1, logical reads 262, physical reads 0, read-ahead reads 0, lob logical reads 0, lob physical reads 0, lob read-ahead reads 0.

    Table 'CorporateStructure'. Scan count 104, logical reads 208, physical reads 0, read-ahead reads 0, lob logical reads 0, lob physical reads 0, lob read-ahead reads 0.

    SQL Server Execution Times:

    CPU time = 0 ms, elapsed time = 8 ms.

    (130 row(s) affected)

    SQL Server Execution Times:

    CPU time = 0 ms, elapsed time = 1 ms.

    SQL Server Execution Times:

    CPU time = 0 ms, elapsed time = 1 ms.

    Table '#131B4459'. Scan count 2, logical reads 1099, physical reads 0, read-ahead reads 0, lob logical reads 0, lob physical reads 0, lob read-ahead reads 0.

    Table 'Worktable'. Scan count 1, logical reads 314, physical reads 0, read-ahead reads 0, lob logical reads 0, lob physical reads 0, lob read-ahead reads 0.

    Table 'CorporateStructure'. Scan count 234, logical reads 472, physical reads 0, read-ahead reads 0, lob logical reads 0, lob physical reads 0, lob read-ahead reads 0.

    SQL Server Execution Times:

    CPU time = 16 ms, elapsed time = 21 ms.

    (156 row(s) affected)

    SQL Server Execution Times:

    CPU time = 0 ms, elapsed time = 1 ms.

    SQL Server Execution Times:

    CPU time = 0 ms, elapsed time = 1 ms.

    Table '#131B4459'. Scan count 2, logical reads 1054, physical reads 0, read-ahead reads 0, lob logical reads 0, lob physical reads 0, lob read-ahead reads 0.

    Table 'Worktable'. Scan count 1, logical reads 12, physical reads 0, read-ahead reads 0, lob logical reads 0, lob physical reads 0, lob read-ahead reads 0.

    Table 'CorporateStructure'. Scan count 390, logical reads 784, physical reads 0, read-ahead reads 0, lob logical reads 0, lob physical reads 0, lob read-ahead reads 0.

    SQL Server Execution Times:

    CPU time = 16 ms, elapsed time = 22 ms.

    (5 row(s) affected)

    SQL Server Execution Times:

    CPU time = 0 ms, elapsed time = 1 ms.

    SQL Server Execution Times:

    CPU time = 0 ms, elapsed time = 1 ms.

    Table '#131B4459'. Scan count 2, logical reads 1044, physical reads 0, read-ahead reads 0, lob logical reads 0, lob physical reads 0, lob read-ahead reads 0.

    Table 'Worktable'. Scan count 1, logical reads 2, physical reads 0, read-ahead reads 0, lob logical reads 0, lob physical reads 0, lob read-ahead reads 0.

    Table 'CorporateStructure'. Scan count 395, logical reads 794, physical reads 0, read-ahead reads 0, lob logical reads 0, lob physical reads 0, lob read-ahead reads 0.

    SQL Server Execution Times:

    CPU time = 15 ms, elapsed time = 22 ms.

    (0 row(s) affected)

    SQL Server Execution Times:

    CPU time = 0 ms, elapsed time = 1 ms.

    SQL Server Execution Times:

    CPU time = 0 ms, elapsed time = 1 ms.

    (395 row(s) affected)

    Table '#131B4459'. Scan count 1, logical reads 4, physical reads 0, read-ahead reads 0, lob logical reads 0, lob physical reads 0, lob read-ahead reads 0.

    SQL Server Execution Times:

    CPU time = 0 ms, elapsed time = 1 ms.

    =====================================

    set statistics io on

    set statistics time on

    declare @TopStructureID_in int

    select @topstructureid_in =

    (select structureid

    from dbo.campaigns

    where campaignid = 560)

    declare @Hierarchy table (

    Lvl int not null,

    StructureID int not null,

    ParentID int,

    primary key (lvl, structureid),

    State varchar(3))

    ;with Hierarchy (Lvl, StructureID, ParentID, RowState)

    as

    (select 0, StructureID, ParentStructureID, c1.RowState

    from dbo.corporatestructure c1

    where structureid = @topstructureid_in

    union all

    select 1 + h2.lvl,

    c2.structureid, c2.parentstructureid, c2.RowState

    from dbo.corporatestructure c2

    inner join hierarchy h2

    on c2.parentstructureid = h2.structureid

    where c2.rowstate != 'del'

    and h2.rowstate != 'del')

    insert into @hierarchy (lvl, structureid, parentid, state)

    select lvl, structureid, parentid, rowstate

    from hierarchy

    select *

    from @hierarchy

    ====================================

    Table 'Campaigns'. Scan count 0, logical reads 2, physical reads 0, read-ahead reads 0, lob logical reads 0, lob physical reads 0, lob read-ahead reads 0.

    SQL Server Execution Times:

    CPU time = 0 ms, elapsed time = 1 ms.

    Table '#441E6E67'. Scan count 0, logical reads 797, physical reads 0, read-ahead reads 0, lob logical reads 0, lob physical reads 0, lob read-ahead reads 0.

    Table 'Worktable'. Scan count 2, logical reads 2371, physical reads 0, read-ahead reads 0, lob logical reads 0, lob physical reads 0, lob read-ahead reads 0.

    Table 'CorporateStructure'. Scan count 790, logical reads 1584, physical reads 0, read-ahead reads 0, lob logical reads 0, lob physical reads 0, lob read-ahead reads 0.

    SQL Server Execution Times:

    CPU time = 31 ms, elapsed time = 24 ms.

    (395 row(s) affected)

    (395 row(s) affected)

    Table '#441E6E67'. Scan count 1, logical reads 4, physical reads 0, read-ahead reads 0, lob logical reads 0, lob physical reads 0, lob read-ahead reads 0.

    SQL Server Execution Times:

    CPU time = 0 ms, elapsed time = 1 ms.

    [/code]

    Both run multiple times, to make sure data is in the cache.

    The loop method (which may differ from the loop you're using), took 62 milliseconds of CPU time, and doesn't improve from that in the next five runs. Took 1,142 total table scans of the CorporateStructure table (the one with the hierarchy in it).

    The CTE took 31 milliseconds CPU as its longest run, and took as little as 15 milliseconds CPU on several of the runs. 790 total scans of the table.

    From that, I have to say the CTE is better in all regards. Faster, and less IO bottleneck.

    - Gus "GSquared", RSVP, OODA, MAP, NMVP, FAQ, SAT, SQL, DNA, RNA, UOI, IOU, AM, PM, AD, BC, BCE, USA, UN, CF, ROFL, LOL, ETC
    Property of The Thread

    "Nobody knows the age of the human race, but everyone agrees it's old enough to know better." - Anon

  • Joe, I haven't been able to work out an efficient way to use your nested sets structure on dynamic hierarchies. On relatively static data, it works great, but I have trouble with it as soon as I need to move levels around, or expand the hierarchy, or anything else other than adding to the "right side" of the hierarchy.

    For example, in a managers to employees hierarchy, if a department is moved to be under a different manager, the nested sets model pretty much forces a complete rebuild of the whole hierarchy, so far as I can tell. A standard hierarchy table (ID and ParentID), allows the same update by changing a single value in a single row.

    I could be missing something on this (probably am), but I just can't get my head around using the nested sets for data that requires any sort of frequent updates.

    I've tested it, and it does work really, really well for selects. But it adds so much complexity and so many referential integrity issues to updates and inserts, that I just can't see how to use it.

    Can you point me to something that helps in that regard?

    Or is it strictly meant for static/nearly static data?

    - Gus "GSquared", RSVP, OODA, MAP, NMVP, FAQ, SAT, SQL, DNA, RNA, UOI, IOU, AM, PM, AD, BC, BCE, USA, UN, CF, ROFL, LOL, ETC
    Property of The Thread

    "Nobody knows the age of the human race, but everyone agrees it's old enough to know better." - Anon

  • I found your loop and CTE are not equivalent. In the loop, you have the code

    WHERE ...

    and c2.structureid not in

    (select structureid

    from @hierarchy)

    which slows it down.

  • peterhe (3/14/2008)


    I found your loop and CTE are not equivalent. In the loop, you have the code

    WHERE ...

    and c2.structureid not in

    (select structureid

    from @hierarchy)

    which slows it down.

    That step is necessary in the loop, and not in the CTE. Otherwise, a repeating hierarchy level causes an error in the loop.

    For example, insert into a hierarchy table:

    ID 1, Parent 2

    ID 2, Parent 1

    or

    ID 1, Parent 1

    In either case, the loop without the Not In (or a left join), will cause an error as it hits the max recursion level. The CTE doesn't have that problem and doesn't need the code.

    For an example of how this can happen:

    Joe is a manager of a sales department

    Joe is also a salesman in that department

    In this case, it is necessary for Joe to be listed as the manager, since that determines his "sales manager" commission, and it is necessary for him to be listed as a salesperson, since that determines his direct sales commissions, and his own sales count for calculating his manager commission. Separating him into two entities with two separate IDs would necessitate giving him two separate paychecks, and would thus mess up income tax, Social Security, Medicare, 401(k), etc., calculations.

    A loop without controls for that kind of thing will go into an infinite loop and will error out. (Yes, I know, real life isn't as neat and tidy like we'd like it to be.)

    I've tested the above scenario in CTEs, and they don't error out and do return the correct hierarchy.

    If you can guarantee that the hierarchy will never include recursive elements, then you don't need that step in the loop.

    The loop without that step, on data pre-tested for non-recursion, is still slower than the CTE on the same data, in my tests.

    - Gus "GSquared", RSVP, OODA, MAP, NMVP, FAQ, SAT, SQL, DNA, RNA, UOI, IOU, AM, PM, AD, BC, BCE, USA, UN, CF, ROFL, LOL, ETC
    Property of The Thread

    "Nobody knows the age of the human race, but everyone agrees it's old enough to know better." - Anon

  • help please.

    I have the following situation:

    I want to populate two related tables

    Person (PersonID, PersonName, PersonLName)

    PersonAddress(PersonAddressID, PersonID, PersonAddr, PersonCity, PersonState, PersonZip, County)

    from a table which contains all the data needed

    MasterList(PersonName, PersonLName, PersonAddr, PersonCity, PersonState, Personzip, County)

    The thing is I am not doing this sequentially, I want to select every 7th person starting from the person in the MasterList table at position 3.

    For example:

    I have 100 people in the master list

    Lets say that I want 30 people to be put into the Persons table and into thier associated address tables.

    I want to be able to increment through the MasterList table starting at the person from position 3, and insert every 7th person thereafter into the tables.

    If I get to the end of the table and I have not reached my 30 people, I need to loop back around starting at a new position - 2 and then repeat selecting every 7th person from then on out.

    Important things:

    1. PersonID is an identity, and an auto - incremented value, but within this loop, when I create my entry for Person, I want to turn around and create an entry for PersonAddress, using the newly created PersonID identity value as a foreign key inside of PersonAddress.

    How should I write a cte to be able to acomplish this ? Thanks for any assistance provided

  • This is probably the wrong place to ask for such help... and we'd really need to know which version of SQL Server you're using. It would probably be better if you started a thread in the correct forum for this.

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

    Change is inevitable... Change for the better is not.


    Helpful Links:
    How to post code problems
    How to Post Performance Problems
    Create a Tally Function (fnTally)

  • I have to agree with Jason Adams on this topic. This article seems to miss one of the most important aspects of DBA work - proper indexing. I currently have the need in an environment to create trees recursively 700+ levels deep and with several million nodes. To perform this using a loop takes 10-15 times longer than to use CTEs. That is using the same indexing between the two sets of coding philosophies. I have seen the rare occasion where a CTE does not outperform the loop by that much, but have yet to see a scenario where the CTE is outperformed by a loop.

    BTW, the loops had been optimized numerous times to gain every ms possible out of them - introduce the CTE's and we are leaps and bounds beyond historic SQL performance levels.

    Jason...AKA CirqueDeSQLeil
    _______________________________________________
    I have given a name to my pain...MCM SQL Server, MVP
    SQL RNNR
    Posting Performance Based Questions - Gail Shaw[/url]
    Learn Extended Events

  • jason brimhall (12/30/2008)


    I have to agree with Jason Adams on this topic. This article seems to miss one of the most important aspects of DBA work - proper indexing. I currently have the need in an environment to create trees recursively 700+ levels deep and with several million nodes. To perform this using a loop takes 10-15 times longer than to use CTEs. That is using the same indexing between the two sets of coding philosophies. I have seen the rare occasion where a CTE does not outperform the loop by that much, but have yet to see a scenario where the CTE is outperformed by a loop.

    BTW, the loops had been optimized numerous times to gain every ms possible out of them - introduce the CTE's and we are leaps and bounds beyond historic SQL performance levels.

    OK, NOW I'm curious: What kind of hierarchy goes that deep?

    [font="Times New Roman"]-- RBarryYoung[/font], [font="Times New Roman"] (302)375-0451[/font] blog: MovingSQL.com, Twitter: @RBarryYoung[font="Arial Black"]
    Proactive Performance Solutions, Inc.
    [/font]
    [font="Verdana"] "Performance is our middle name."[/font]

  • Binary Trees in the MLM industry.

    Jason...AKA CirqueDeSQLeil
    _______________________________________________
    I have given a name to my pain...MCM SQL Server, MVP
    SQL RNNR
    Posting Performance Based Questions - Gail Shaw[/url]
    Learn Extended Events

  • What is the MLM industry and why would they need hierarchies that deep?

    [font="Times New Roman"]-- RBarryYoung[/font], [font="Times New Roman"] (302)375-0451[/font] blog: MovingSQL.com, Twitter: @RBarryYoung[font="Arial Black"]
    Proactive Performance Solutions, Inc.
    [/font]
    [font="Verdana"] "Performance is our middle name."[/font]

  • MLM=multi-level marketing.

    ----------------------------------------------------------------------------------
    Your lack of planning does not constitute an emergency on my part...unless you're my manager...or a director and above...or a really loud-spoken end-user..All right - what was my emergency again?

  • Ah. OK....

    So at 700 levels and say 10 million nodes, that would mean that each node had an average of 1.023 children? Wow, that's a pretty strung-out hierarchy.

    [font="Times New Roman"]-- RBarryYoung[/font], [font="Times New Roman"] (302)375-0451[/font] blog: MovingSQL.com, Twitter: @RBarryYoung[font="Arial Black"]
    Proactive Performance Solutions, Inc.
    [/font]
    [font="Verdana"] "Performance is our middle name."[/font]

  • some are worse than others as far as strung out. Most of it depends on the business model employed. I have seen one tree strung out to about 1200 levels but with only 500k nodes.

    Jason...AKA CirqueDeSQLeil
    _______________________________________________
    I have given a name to my pain...MCM SQL Server, MVP
    SQL RNNR
    Posting Performance Based Questions - Gail Shaw[/url]
    Learn Extended Events

Viewing 15 posts - 16 through 30 (of 32 total)

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