The Common Table Expression (CTE)Â is a great tool in T-SQL. The CTE provides a mechanism to define a query that can be easily reused over and over within another query. The CTE also provides a mechanism for recursion which, though a little dangerous and overused, is extremely handy for certain types of queries. However, the CTE has a very unfortunate name. Over and over I’ve had to walk people back from the “Table” in Common Table Expression. The CTE is just a query. It’s not a table. It’s not providing a temporary storage space like a table variable or a temporary table. It’s just a query. Think of it more like a temporary view, which is also just a query.
Every time I explain this, there are people who don’t believe me. They point to the “Table” in the name, “See. Says so right there. It’s a table.”
It’s not and I can prove it. Let’s create a relatively simple CTE and use it in a query:
WITH MyCTE AS (SELECT c.CustomerName, cc.CustomerCategoryName FROM Sales.Customers AS c JOIN Sales.CustomerCategories AS cc ON cc.CustomerCategoryID = c.CustomerCategoryID WHERE c.CustomerCategoryID = 4) SELECT * FROM MyCTE;
Now, I’m going to run the query within the CTE and the CTE together as two statements in a batch and capture the execution plans:
On the top, the CTE, on the bottom, the query. You’ll note that the execution plans are identical. They each have the exact same Query Plan Hash value in the properties, 0x88EFD2B7C165E667, even though they have different Query Hash values, 0x192FFC125A08CC35 and 0xFEB7F2BCAC853CD5, respectively. Further, if I capture the query metrics using extended events, I get identical reads and, on average, identical execution times:
This is because, there is no table being created. The data is not treated differently. A CTE is just a query, not some type of temporary storage.
Heck, let’s do one more thing. Let’s use the latest SSMS plan comparison tool and highlight one of the operators to see what differences there are internally in the plan:
I don’t see a lot of differences. In fact, I don’t see any. That’s because the optimizer recognizes these two queries as identical. If it was loading data into temporary storage, you would see differences in something. We don’t. This is because, despite the somewhat unfortunate emphasis that gets placed on the Table portion of the name, the emphasis of the name, Common Table Expression, should be on the word Expression.
I will point out an interesting difference, especially useful for those who plug in CTEs everywhere, whether it’s needed or not. Let’s look at the properties of the two plans:
You can see the similarities and differences that I pointed out earlier in the Statement, Query Hash and Query Plan Hash, as well as the Estimated Subtree Cost and others. What’s truly interesting is that the CompileCPU, CompileMemory and CompileTime for the CTE is higher than the regular query. While the CTE is just a query, it’s a query that adds a non-zero overhead when used, and therefore, should only be used where appropriate (good gosh, I’ve seen people put it EVERWHERE, on every single query, don’t do that).
Hopefully, this is enough to establish, truly, completely, and thoroughly, that the Common Table Expression is an expression, not a table.
Yeah, I did this before, but it keeps coming up, so I tried a different approach. Let’s see if the word gets out. Your Common Table Expression is not a table.
I love talking about execution plans and query tuning. I’ll be doing this at an all day pre-con at SQLServer Geeks Annual Summit in Bangalore India.
Don’t miss your chance to an all day training course on execution plans before SQL Saturday Oslo in September.
They are also called inline views, which might be a more descriptive name
Certainly a more accurate one.
One of the things about a CTE is that every time it is called, the entire query in that CTE is re-run. This is no different than taking that entire query and using it as a sub-query in all of those places where the CTE is referenced. Therefore, I like to describe a CTE as a “pre-defined sub-query”.
That sounds good too.
[…] Grant Fritchey shows that CTEs are not tables; they’re expressions: […]
I read it as Common Table-Expression so it’s nature is clear to me (IE: not a table).
Richard,
That’s so perfect I had to go and quickly look at the documentation to see if I just been misreading it forever. No joy there. It wasn’t typed the way you have. More is the pity. That’s perfect.
Speaking as a programmer, I tend to think of ’em as subroutines. (And notions of cohesion apply)
I think “every time it is called, the entire query in that CTE is re-run” is a very important performance aspect (limitation?) of CTEs which is often overlooked.
A CTE may be like a view or an expression, but it also does create work tables that are scoped to the execution of a single SQL statement.
https://msdn.microsoft.com/en-us/library/ms345368.aspx
{
Common table expression queries:
A common table expression can be thought of as a temporary result set that is defined within the execution scope of a single SELECT, INSERT, UPDATE, DELETE, or CREATE VIEW statement.
When the query plan for a common table expression query uses a spool operator to save intermediate query results, the Database Engine creates a work table in tempdb to support this operation.
}
This work table would be created and gone by the time the script is done so it could appear that the CTE has no table. A simple CTE could actually work without creating a work table I suspect, but a more complex one would certainly create a work table.
The optimizer does not automatically create a spool for a CTE. There is no spool in the example above. You would see it. It’s not there. The optimizer can create a spool any time it thinks it needs to reuse a data set, say to avoid scanning a table over and over when doing a loop join, just as an example. It’s not a product or an automatic part of a CTE. It completely depends on the query, but, so does the creation of a spool in any case. You would see it in the execution plan if that’s what it was doing. It’s not.
The documentation you link to says “when the query plan for a CTE query uses a spool operator” and the operative word is “when”. If there is not spool needed, none is created.
[…] Common Table Expression, Just a Name […]
[…] Common Table Expression, Just a Name: да, Ñлово «Table» в Common Table Expression Ñбивает многих. Ðа Ñамом деле Ñто проÑто подзапроÑ, который не материализует данные (иÑключение: рекурÑивный CTE вÑегда материализует данные Ð´Ð»Ñ Ð¿ÐµÑ€ÐµÐ¸ÑпользованиÑ). ÐÐµÐ±Ð¾Ð»ÑŒÑˆÐ°Ñ Ð¼ÐµÑ‚ÐºÐ°Ñ Ð·Ð°Ð¼ÐµÑ‚ÐºÐ° Гранта Фритчи быÑтро проÑÑнÑет Ñтот вопроÑ. […]
[…] https://www.scarydba.com/2016/07/18/common-table-expression-just-a-name/ […]