Selecting FROM
a Common Table Expression (CTE)
A common table expression — or CTE — is a more complex variant of the derived table, but it is also more powerful.A preamble, starting with the keyword WITH
, defines one or more named CTEs, each with an optional column aliases list.The main query, which follows the preamble, can then access these CTEs as if they were regular tables or views.The CTEs go out of scope once the main query has run to completion.
For a full discussion of CTEs, please refer to the section [fblangref50-dml-select-cte].
The following is a rewrite of our derived table example as a CTE:
with vars (b, D, denom) as (
select b, b*b - 4*a*c, 2*a from coeffs
)
select
iif (D >= 0, (-b - sqrt(D)) / denom, null) sol_1,
iif (D > 0, (-b + sqrt(D)) / denom, null) sol_2
from vars
Except for the fact that the calculations that have to be made first are now at the beginning, this isn’t a great improvement over the derived table version.However, we can now also eliminate the double calculation of sqrt(D)
for every row:
with vars (b, D, denom) as (
select b, b*b - 4*a*c, 2*a from coeffs
),
vars2 (b, D, denom, sqrtD) as (
select b, D, denom, iif (D >= 0, sqrt(D), null) from vars
)
select
iif (D >= 0, (-b - sqrtD) / denom, null) sol_1,
iif (D > 0, (-b + sqrtD) / denom, null) sol_2
from vars2
The code is a little more complicated now, but it might execute more efficiently (depending on what takes more time: executing the SQRT
function or passing the values of b
, D
and denom
through an extra CTE).Incidentally, we could have done the same with derived tables, but that would involve nesting.
Important
|
All columns in the CTE will be evaluated as many times as they are specified in the main query.This is important, as it can lead to unexpected results when using non-deterministic functions.The following shows an example of this.
The result if this query produces three different values: C1 80AAECED-65CD-4C2F-90AB-5D548C3C7279 C2 C1214CD3-423C-406D-B5BD-95BF432ED3E3 C3 EB176C10-F754-4689-8B84-64B666381154 To ensure a single result of the
This query produces a single result for all three columns: C1 80AAECED-65CD-4C2F-90AB-5D548C3C7279 C2 80AAECED-65CD-4C2F-90AB-5D548C3C7279 C3 80AAECED-65CD-4C2F-90AB-5D548C3C7279 An alternative solution is to wrap the
This is an artifact of the current implementation.This behaviour may change in a future Firebird version. |