8
0
mirror of https://github.com/FirebirdSQL/firebird.git synced 2025-01-22 20:43:02 +01:00

Documentation for GTT and CTE features

This commit is contained in:
hvlad 2007-03-14 13:51:41 +00:00
parent 315e79a31d
commit b845c06efb
2 changed files with 232 additions and 0 deletions

View File

@ -0,0 +1,155 @@
SQL Language Extension: common table expressions
Author:
Vlad Horsun <hvlad@users.souceforge.net>
based on work by Paul Ruizendaal for Fyracle project
Function:
Common Table Expressions is like views, locally defined within main query.
From the engine point of view CTE is a derived table so no intermediate
materialization is performed.
Recursive CTE allow to create recursive queries. It works as below :
engine start execution from non-recursive members,
for each evaluated row engine start execution of each recursive member using
current row values as parameters,
if current instance of recursive member produced no rows engine returns one
step back and get next row from previous resultset
Memory and CPU overhead of recursive CTE is much less than overhead of
recursive stored procedures. Currently recursion depth is limited by hardcoded
value of 1024
Syntax:
select : select_expr for_update_clause lock_clause
select_expr : with_clause select_expr_body order_clause rows_clause
| select_expr_body order_clause rows_clause
with_clause : WITH RECURSIVE with_list
| WITH with_list
with_list : with_item
| with_item ',' with_list
with_item : symbol_table_alias_name derived_column_list AS '(' select_expr ')'
select_expr_body : query_term
| select_expr_body UNION distinct_noise query_term
| select_expr_body UNION ALL query_term
Or, in less formal format :
WITH [RECURSIVE]
CTE_A [(a1, a2, …)]
AS ( SELECT … ),
CTE_B [(b1, b2, …)]
AS ( SELECT … ),
...
SELECT ...
FROM CTE_A, CTE_B, TAB1, TAB2 ...
WHERE ...
Rules of non-recursive common table expressions :
Several table expressions can be defined at one query
Any SELECTs clause can be used in table expressions
Table expressions can reference each other
Table expressions can be used within any part of main query or another
table expression
The same table expression can be used several times in main query
Table expressions can be used in INSERT, UPDATE and DELETE statements
(as subqueries of course)
Table expressions can be used in procedure language also
WITH statements can not be nested
References between expressions should not have a loops
Example of non-recursive common table expressions :
WITH
DEPT_YEAR_BUDGET AS (
SELECT FISCAL_YEAR, DEPT_NO, SUM(PROJECTED_BUDGET) AS BUDGET
FROM PROJ_DEPT_BUDGET
GROUP BY FISCAL_YEAR, DEPT_NO
)
SELECT D.DEPT_NO, D.DEPARTMENT,
B_1993.BUDGET AS B_1993, B_1994.BUDGET AS B_1994,
B_1995.BUDGET AS B_1995, B_1996.BUDGET AS B_1996
FROM DEPARTMENT D
LEFT JOIN DEPT_YEAR_BUDGET B_1993
ON D.DEPT_NO = B_1993.DEPT_NO AND B_1993.FISCAL_YEAR = 1993
LEFT JOIN DEPT_YEAR_BUDGET B_1994
ON D.DEPT_NO = B_1994.DEPT_NO AND B_1994.FISCAL_YEAR = 1994
LEFT JOIN DEPT_YEAR_BUDGET B_1995
ON D.DEPT_NO = B_1995.DEPT_NO AND B_1995.FISCAL_YEAR = 1995
LEFT JOIN DEPT_YEAR_BUDGET B_1996
ON D.DEPT_NO = B_1996.DEPT_NO AND B_1996.FISCAL_YEAR = 1996
WHERE EXISTS (SELECT * FROM PROJ_DEPT_BUDGET B WHERE D.DEPT_NO = B.DEPT_NO)
Rules of recursive common table expressions :
Recursive CTE have reference to itself
Recursive CTE is an UNION of recursive and non-recursive members
At least one non-recursive member (anchor) must be present
Non-recursive members are placed first in UNION
Recursive members are separated from an anchor members and from each
other with UNION ALL clause
References between CTEs should not have a loops
Aggregates (DISTINCT, GROUP BY, HAVING) and aggregate functions (SUM,
COUNT, MAX etc) are not allowed in recursive members
Recursive member can have only one reference to itself and only in FROM clause
Recursive reference can not participate in outer joins
Example of recursive common table expressions
WITH RECURSIVE
DEPT_YEAR_BUDGET AS
(
SELECT FISCAL_YEAR, DEPT_NO, SUM(PROJECTED_BUDGET) AS BUDGET
FROM PROJ_DEPT_BUDGET
GROUP BY FISCAL_YEAR, DEPT_NO
),
DEPT_TREE AS
(
SELECT DEPT_NO, HEAD_DEPT, DEPARTMENT, CAST('' AS VARCHAR(255)) AS INDENT
FROM DEPARTMENT
WHERE HEAD_DEPT IS NULL
UNION ALL
SELECT D.DEPT_NO, D.HEAD_DEPT, D.DEPARTMENT, H.INDENT || ' '
FROM DEPARTMENT D JOIN DEPT_TREE H
ON D.HEAD_DEPT = H.DEPT_NO
)
SELECT D.DEPT_NO,
D.INDENT || D.DEPARTMENT AS DEPARTMENT,
B_1993.BUDGET AS B_1993,
B_1994.BUDGET AS B_1994,
B_1995.BUDGET AS B_1995,
B_1996.BUDGET AS B_1996
FROM DEPT_TREE D
LEFT JOIN DEPT_YEAR_BUDGET B_1993
ON D.DEPT_NO = B_1993.DEPT_NO AND B_1993.FISCAL_YEAR = 1993
LEFT JOIN DEPT_YEAR_BUDGET B_1994
ON D.DEPT_NO = B_1994.DEPT_NO AND B_1994.FISCAL_YEAR = 1994
LEFT JOIN DEPT_YEAR_BUDGET B_1995
ON D.DEPT_NO = B_1995.DEPT_NO AND B_1995.FISCAL_YEAR = 1995
LEFT JOIN DEPT_YEAR_BUDGET B_1996
ON D.DEPT_NO = B_1996.DEPT_NO AND B_1996.FISCAL_YEAR = 1996

View File

@ -0,0 +1,77 @@
SQL Language Extension: global temporary tables
Author:
Vlad Horsun <hvlad@users.souceforge.net>
Function:
Global temporary tables (GTTs) are tables with permanent metadata, stored
in the system catalogue, but with the temporary data. GTT's may be of two kinds -
with the data, persistent within lifetime of connection in which the given GTT
was referenced, and with the data, persistent within only during lifetime of
referencing transaction. The data from different connections (transactions) are
isolated from each other, but metadata of the global temporary table are shared
between all connections and transactions.
Syntax and rules :
CREATE GLOBAL TEMPORARY TABLE
[ON COMMIT <DELETE | PRESERVE> ROWS]
Creates metadata of the temporary table in the system catalogue.
Clause ON COMMIT sets a kind of the temporary table:
ON COMMIT PRESERVE ROWS : data of the given table after end of transaction
remains in database until end of connection
ON COMMIT DELETE ROWS : data of the given table are deleted from database
immediately after end of transaction
If optional clause ON COMMIT is not specified ON COMMIT DELETE ROWS is
used by default.
CREATE GLOBAL TEMPORARY TABLE - usual DDL statement and processed by the
engine the same way as operator CREATE TABLE. Therefore impossible create or
drop GTT within stored procedure or trigger.
GTT differs from permanent tables by value of RDB$RELATIONS.RDB$RELATION_TYPE :
GTT with ON COMMIT PRESERVE ROWS option have value 4 in RDB$RELATION_TYPE field
while GTT with ON COMMIT DELETE ROWS option have value of 5. See full list of
values in RDB$TYPES
GTT may have indexes, triggers, field level and table level constraints - as
well as usual tables.
All kinds of constraints between temporary and persistent tables follow
the rules below:
a) references between persistent and temporary tables are forbidden
b) GTT with ON COMMIT PRESERVE ROWS can't have reference on GTT with
ON COMMIT DELETE ROWS
c) Domain constraints can't have reference on GTT.
Implementation details:
GTT instance (set of data rows created by and visible within given connection
or transaction) created when it first referenced, usually at statement prepare
time. Each instance has its own private set of pages on which data and indexes
are stored. Data rows and indexes have the same physical storage layout as
permanent tables.
When connection or transaction ends all pages of an GTT instance are released
immediately (this is similar as when you do DROP TABLE but metatada remains in
database of course). This is much quicker than traditional row by row delete +
garbage collection of deleted record versions. DELETE triggers are not fired in
this case.
Data and index pages of all of the GTTs instances placed in separate temporary
files. Each connection have its own temporary file created when this connection
first referenced some GTT. Also this temporary files always opened with “Forced
Writes = OFF” setting despite of database setting.
There are no limit on number of GTT instances. If you have N transactions
active simultaneously and each transaction have referenced some GTT then youll
have N GTTs instances.