Temp Table 'vs' Table Variable 'vs' CTE.

  • TheSQLGuru (8/21/2009)


    Just to make clear, it isn't JUST about the number of rows you put into a table variable/temp table that matters. I can also be the actual VALUE(s) therein. For example, if you have a table variable with just 1 row, and field1's value is 'abc' and you join that table to another table on field1, you can get horrible performance if the data in the joined table is skewed such that a large percentage of the values are 'abc' due to nested loop plan. A temp table could have stats on field1 and discover that a hash/merge join would be much more efficient.

    You sure about that one? I mean the optimizer assumes one row. If it has one row, it's pretty likely to be able to come up with a plan that uses one row correctly, no? That's, to a degree, regardless of what's in the row.

    "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

  • TheSQLGuru (8/21/2009)


    Just to make clear, it isn't JUST about the number of rows you put into a table variable/temp table that matters. I can also be the actual VALUE(s) therein. For example, if you have a table variable with just 1 row, and field1's value is 'abc' and you join that table to another table on field1, you can get horrible performance if the data in the joined table is skewed such that a large percentage of the values are 'abc' due to nested loop plan. A temp table could have stats on field1 and discover that a hash/merge join would be much more efficient.

    As Jeff Moden says, test it.

    I just ran a series of tests. I'm going to try to put together some more. The basic results were that regardless of the value or the type of table, temp or variable, I got identical execution plans. However, I'm not saying you're wrong. I did see differences in the estimated values, not for the temporary table or the table variable, but for the table they were joined against. The variation wasn't sufficient to result in a different execution plan in the tests I've run so far. I'm going to try for some more extreme data sets to see if I can force a difference.

    "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

  • If you do get a difference, please blog it. Also, if you do get a difference, try OPTION (RECOMPILE) on the query, see if there's any change. Shouldn't be, recompile just lets the optimiser know the number of rows for table var, not the data distribution, but should be included for completeness.

    Gail Shaw
    Microsoft Certified Master: SQL Server, MVP, M.Sc (Comp Sci)
    SQL In The Wild: Discussions on DB performance with occasional diversions into recoverability

    We walk in the dark places no others will enter
    We stand on the bridge and no one may pass
  • Grant Fritchey (8/21/2009)


    TheSQLGuru (8/21/2009)


    Just to make clear, it isn't JUST about the number of rows you put into a table variable/temp table that matters. I can also be the actual VALUE(s) therein. For example, if you have a table variable with just 1 row, and field1's value is 'abc' and you join that table to another table on field1, you can get horrible performance if the data in the joined table is skewed such that a large percentage of the values are 'abc' due to nested loop plan. A temp table could have stats on field1 and discover that a hash/merge join would be much more efficient.

    You sure about that one? I mean the optimizer assumes one row. If it has one row, it's pretty likely to be able to come up with a plan that uses one row correctly, no? That's, to a degree, regardless of what's in the row.

    Yes, I am sure, and it is ALL about what is in the row. If you join to a table on 1 (or a few) values and you hit 90% of the rows in the join table do you really want to do that using a nested loop plan??

    Here is the typical example I present for this. It uses 3 values (as opposed to a single row - but the reasoning is the same), with distributions shown at the top of the script. AdventureWorks on sql 2005 here

    select ProductID, count(*)

    from Production.TransactionHistory

    group by ProductID

    order by count(*)

    ProductID

    ----------- -----------

    843 1

    849 1

    855 1

    ...

    921 2859

    873 3003

    870 4187

    dbcc freeproccache

    go

    set statistics io on

    set statistics time on

    go

    declare @tab table (a int not null)

    insert @tab values (843)

    insert @tab values (849)

    insert @tab values (855)

    select *

    from Production.TransactionHistory h

    inner join @tab t on t.a = h.ProductID

    --18 logical reads, nested loop plan

    delete @tab

    dbcc freeproccache

    insert @tab values (870)

    insert @tab values (873)

    insert @tab values (921)

    select *

    from Production.TransactionHistory h

    inner join @tab t on t.a = h.ProductID

    --30805 logical reads, nested loop plan

    dbcc freeproccache

    create table #tab (a int not null)

    insert #tab values (843)

    insert #tab values (849)

    insert #tab values (855)

    select *

    from Production.TransactionHistory h

    inner join #tab t on t.a = h.ProductID

    --18 logical, nested loop plan

    delete #tab

    dbcc freeproccache

    insert #tab values (870)

    insert #tab values (873)

    insert #tab values (921)

    select *

    from #tab t

    inner join Production.TransactionHistory h on t.a = h.ProductID

    --792 logical reads, hash join plan

    Best,
    Kevin G. Boles
    SQL Server Consultant
    SQL MVP 2007-2012
    TheSQLGuru on googles mail service

  • TheSQLGuru (8/21/2009)


    If you join to a table on 1 (or a few) values and you hit 90% of the rows in the join table do you really want to do that using a nested loop plan??

    Depends which table's the inner and which is the outer. In this case, the small table would be better as the outer table. Though whether the optimiser will do that is another matter.

    Gail Shaw
    Microsoft Certified Master: SQL Server, MVP, M.Sc (Comp Sci)
    SQL In The Wild: Discussions on DB performance with occasional diversions into recoverability

    We walk in the dark places no others will enter
    We stand on the bridge and no one may pass
  • The data I initially tested with was distributed about the same as yours. I was using AdventureWorks.SalesOrderDetail & the ProductID. 870 has 4,688 rows & 897 has 2 rows. But I kept getting identical execution plans for table variables & temporary tables. I'm planning on bumping up the disparity much more widely to see where it breaks down.

    "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

  • GilaMonster (8/21/2009)


    TheSQLGuru (8/21/2009)


    If you join to a table on 1 (or a few) values and you hit 90% of the rows in the join table do you really want to do that using a nested loop plan??

    Depends which table's the inner and which is the outer. In this case, the small table would be better as the outer table. Though whether the optimiser will do that is another matter.

    I forced the order on the loop join with table var and as expected the reads went way down, but I couldn't seem to get the optimizer to pick that plan of it's own volition. I note that the CPU time for the 'correct' plan was 2-4X more than the optimizer-derived one.

    select *

    from Production.TransactionHistory h

    inner join @tab t on t.a = h.ProductID

    option (force order)

    Best,
    Kevin G. Boles
    SQL Server Consultant
    SQL MVP 2007-2012
    TheSQLGuru on googles mail service

  • Old topic but still relavent...

    In my previous job, I always used CTEs and they were much faster when compared to temp tables.

    In the current place, strangely enough Temp tables almost always win by a mile.

    Trust me; what I say is true.

    Otherwise, in both places I have been writing Procs for SSRS reports against very similar databases in terms of volume, size and indexes.

    From a processing engine stand point would it matter as to how servers are configured, so as to differ in how CTEs and Temp table execution is considered.

  • sivapragasam2000 (5/6/2013)


    Old topic but still relavent...

    In my previous job, I always used CTEs and they were much faster when compared to temp tables.

    In the current place, strangely enough Temp tables almost always win by a mile.

    Trust me; what I say is true.

    Otherwise, in both places I have been writing Procs for SSRS reports against very similar databases in terms of volume, size and indexes.

    From a processing engine stand point would it matter as to how servers are configured, so as to differ in how CTEs and Temp table execution is considered.

    If you posted this as a new question you'd get a lot more answers.

    In a nutshell, yeah, the server configuration matters. Faster/more memory, faster/more CPU, faster/more disks or the opposite absolutely have an affect on queries. That's why so many people just throw hardware at query problems rather than try to take the time to understand the fundamental issues. It really is easier, but usually far less effective.

    As to the specifics of your situation, why would a CTE or a temp table be faster? It completely depends on the underlying structures, the indexes, the code, the statistics, and yeah, hardware. Without knowing more I couldn't hazard a guess. But remember that CTE are nothing but queries. No data is stored or special statistics are generated. Temp tables are data storage with statistics. Those differences in behavior will lead to different behaviors of queries in different circumstances.

    "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

  • Nice explanation.esayly to understand

  • check below url for better clarity.

    http://www.ssktutorials.com/2016/06/difference-between-cte-and-temp-table.html

  • This is a seven year old thread, so I shouldn't comment on it, but I can't help but point out that both links in the last two posts which presume to explain the differences between table variables & temporary tables & CTEs (well, that's left off the second post), fail to mention statistics. The statistics difference between table variables and temporary tables is probably the most fundamental difference. To miss that is basically to miss the point completely.

    "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

  • The second article is written in growlingly poor English. I read it this morning. Despite some relief - in the comments - from the frustrating language and the glaring omissions I had no patience left for the first article. Until now.

    How about this for "Factual Misunderstanding of the Week":

    "Difference between CTE and Temp Table and Table Variable

    Temp Table or Table variable or CTE are commonly used for storing data temporarily in SQL Server. In this article, you will learn the differences among these three.

    Common Table expressions (CTE)

    Common Table expressions (CTE) was introduced with SQL Server 2005. It is a temporary result set..."

    “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

  • growlingly poor English

    :hehe::hehe::hehe: +1

    I never heard the word growlingly before so I looked up the Webster definition.

    Growl´ing`ly

    adv.1.In a growling manner.

    "I cant stress enough the importance of switching from a sequential files mindset to set-based thinking. After you make the switch, you can spend your time tuning and optimizing your queries instead of maintaining lengthy, poor-performing code."

    -- Itzik Ben-Gan 2001

  • ChrisM@Work (8/23/2016)


    The second article is written in growlingly poor English. I read it this morning. Despite some relief - in the comments - from the frustrating language and the glaring omissions I had no patience left for the first article. Until now.

    How about this for "Factual Misunderstanding of the Week":

    "Difference between CTE and Temp Table and Table Variable

    Temp Table or Table variable or CTE are commonly used for storing data temporarily in SQL Server. In this article, you will learn the differences among these three.

    Common Table expressions (CTE)

    Common Table expressions (CTE) was introduced with SQL Server 2005. It is a temporary result set..."

    Good gosh. I glossed right over that.

    "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

Viewing 15 posts - 31 through 45 (of 50 total)

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