Why does query error with empty result set in SQL Server 2012?
An initial look at the execution plans shows that the expression 1/0
is defined in the Compute Scalar operators:
Now, even though execution plans do start executing at the far left, iteratively calling Open
and GetRow
methods on child iterators to return results, SQL Server 2005 and later contains an optimization whereby expressions are often only defined by a Compute Scalar, with evaluation deferred until a subsequent operation requires the result:
In this case, the expression result is only needed when assembling the row for return to the client (which you can think of occurring at the green SELECT
icon). By that logic, deferred evaluation would mean the expression is never evaluated because neither plan generates a return row. To labour the point a little, neither the Clustered Index Seek nor the Table Scan return a row, so there is no row to assemble for return to the client.
However, there is a separate optimization whereby some expressions can be identified as runtime constants and so evaluated once before query execution begins.
In this case*, an indication this has occurred can be found in the showplan XML (Clustered Index Seek plan on the left, Table Scan plan on the right):
I wrote more about the underlying mechanisms and how they can affect performance in this blog post. Using information provided there, we can modify the first query so both expressions are evaluated and cached before execution starts:
select 1/0 * CONVERT(integer, @@DBTS)
from #temp
where id = 1
select 1/0
from #temp2
where id = 1
Now, the first plan also contains a constant expression reference, and both queries produce the error message. The XML for the first query contains:
More information: Compute Scalars, Expressions and Performance
An example where an error is reported due to runtime constant caching, but there is no indication in the execution plan (graphical or XML):
SELECT TOP (1) id
FROM #temp2
WHERE id = 1
ORDER BY 1/0;
I am going to intelligently guess (and in the process probably attract a SQL Server guru who might give a really detailed answer).
The first query approaches the execution as:
- Scan the primary key index
- Look up the values in the data table needed for the query
It chooses this path because you have a where
clause on the primary key. It never gets to the second step, so the query does not fail.
The second doesn't have a primary key to run on, so it approaches the query as:
- Do a full table scan of the data and retrieve the necessary values
One of those values is 1/0
causing the problem.
This is an example of SQL Server optimizing the query. For the most part, this is a good thing. SQL Server will move conditions from the select
into the table scan operation. This often saves steps in the evaluation of the query.
But, this optimization is not an unmitigated good thing. In fact, it seems to violate the SQL Server documentation itself which says that the where
clause is evaluated prior to the select
. Well, they might have some erudite explanation for what this means. To most humans, though, logically processing the where
before the select
would mean (among other things) "do not generate select
-clause errors on rows not returned to the user".