SQL Clone
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


Explain the execution of a cte


Explain the execution of a cte

Author
Message
er.mayankshukla
er.mayankshukla
SSCrazy
SSCrazy (2.6K reputation)SSCrazy (2.6K reputation)SSCrazy (2.6K reputation)SSCrazy (2.6K reputation)SSCrazy (2.6K reputation)SSCrazy (2.6K reputation)SSCrazy (2.6K reputation)SSCrazy (2.6K reputation)

Group: General Forum Members
Points: 2562 Visits: 585
Hi,
I had written a cte which has come complex joins and selected 7 columns for output. It contained 4 million rows.
Now I write my Cte like this:

with cte as
(
select col1,col2,col3,col4,col5,col6,col7
from
tbl1 Join tbl2 ....
)
(above code is just for reference)

When I execute :
select * from cte : takes 14 secs
select count(1) from cte : takes 1 sec.

Now my question is, when I ask for the count does SQL ignore all the columns defined in the cte ?
Which would essentially mean that based on how you query CTE, the definition would be compiled ?
John Mitchell-245523
John Mitchell-245523
SSC Guru
SSC Guru (81K reputation)SSC Guru (81K reputation)SSC Guru (81K reputation)SSC Guru (81K reputation)SSC Guru (81K reputation)SSC Guru (81K reputation)SSC Guru (81K reputation)SSC Guru (81K reputation)

Group: General Forum Members
Points: 81068 Visits: 17956
What is the result of the second query? My guess is that the first one takes so long because it has to return all the data to the client. The second one is only returning a single number. Another possibility is that a COUNT can make use of narrower indexes than a query that needs to return multiple columns and therefore fewer page reads were not necessary.

Let's not waste our time guessing, though. Have you compared the execution plans?

John
er.mayankshukla
er.mayankshukla
SSCrazy
SSCrazy (2.6K reputation)SSCrazy (2.6K reputation)SSCrazy (2.6K reputation)SSCrazy (2.6K reputation)SSCrazy (2.6K reputation)SSCrazy (2.6K reputation)SSCrazy (2.6K reputation)SSCrazy (2.6K reputation)

Group: General Forum Members
Points: 2562 Visits: 585
Yes the plans are different and with select count(1) I do not see other columns being pulled up.
That is my question, whether the execution of the query underlying cte depends on the way cte is queried.
Thom A
Thom A
SSC-Forever
SSC-Forever (46K reputation)SSC-Forever (46K reputation)SSC-Forever (46K reputation)SSC-Forever (46K reputation)SSC-Forever (46K reputation)SSC-Forever (46K reputation)SSC-Forever (46K reputation)SSC-Forever (46K reputation)

Group: General Forum Members
Points: 46222 Visits: 15719
er.mayankshukla - Wednesday, December 27, 2017 5:35 AM
That is my question, whether the execution of the query underlying cte depends on the way cte is queried.

Yes. An CTE is an expression. It's not (like people seem to think) a temporary table or variable. They don't behave the same same.

Say you have a table which is 500 columns wide, and you have 100,000 rows stored in it. You have a CLUSTERED INDEX on the Column PrimaryKey. Doing something simple like;
WITH CTE AS(
SELECT *
FROM MyTable)
SELECT PrimaryKey
FROM CTE
WHERE PrimaryKey <= 1000;


Wouldn't mean that the data engine needs to scan all the others columns. Why? Because they aren't referenced in the end statement (note that this isn't always true, it depends on what the CTE is doing, but for a simple query like this, it is), you're only worried about PrimaryKey. On the other hand, if you were to use a Temporary table:
SELECT *
INTO #Temp
FROM MyTable;

SELECT PrimaryKey
FROM #Temp
WHERE PrimaryKey <= 1000;


Now, EVERY column and row's data needs to be read and stored in the Temporary Table. Then, you' very likely have a table scan, rather than a Index Seek, on the Temporary table, as it's not indexed. The two would perform entirely differently.



Thom~
Excuse my typos and sometimes awful grammar. My fingers work faster than my brain does :-P

Please always remember to encapsulate your code in IFCode Markup. For example [code=sql] [/code].
Click here to read Jeffs Guide on how to post SQL questions, and get swift and helpful answers from the community
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