Author: | Hannu Krosing |
---|---|
Contact: | hannu@tm.ee |
Version: | 0.1 |
This is my initial attempt to get a grip of SQL99 syntax for recursive queries.
Also I want to get better understanding of semantics and behaviour of SEARCH and (especially) CYCLE clauses.
I think the Grammar part is fairly complete for working from it.
This document is prepared using docutils. It could also made to serve as a starting point for the final documentation after automatically converting it to DocBook format.
WITH clause is a way to specify subqueries in-line, similar to the FROM clause.
The main difference between them is the namspace in which they are evalkuated - the subqueries defined in FROM clause don't see any other subquery from that FROM clause, while subqueries defined in WITH clause see either the subqueries that preceed them in text order (simple WITH) or all their sibling subqueries (WITH RECURSIVE).
The simple WITH is mainly useful in cases where there are many subqueries using each other. This enables one to write (arguably) cleaner code:
WITH b(b_a,b_b) AS (SELECT a_a, a_b FROM a) c(c_a, c_b) AS (SELECT b_a, b_b FROM b) SELECT c_a + c_b FROM c;
instead of writing it as embedded query in FROM:
SELECT c_a + c_b FROM ( SELECT b_a as c_a, b_b as c_b FROM ( SELECT a_a AS b_a, a_b AS b_a FROM a ) b ) c;
or when some subquery is used multiple times.
The WITH RECURSIVE is more interesting, as it enables writing recursive queries which allow one to fetch hierarchies represented as parent-child relationships in relational tables:
-- get all ancestors of child 6 (root.child2.child5.child6) with recursive descendants (id,parent_id,name) as ( select id,parent_id,name from t where id = 6 union select t.id,t.parent_id,t.name from t, descendants where t.id = descendants.parent_id ) select * from descendants ;
There is no way to write a recursive queries in SQL99 without using WITH RECURSIVE.
The following samples will demonstrate the use of WITH [RECURSIVE].
this sample demonstrates using WITH as inline replacement for defining VIEW's
this sample demonstrates recursive query
this sample demonstrates controlling recursion with the CYCLE clause
this sample demonstrates specifying recursive search order with the SEARCH clause
psql help text for it should probably look like this:
psql=# \h with WITH [ RECURSIVE ] query_name [ ( column_alias_list ) ] [ AS ] ( select ) [...] select [ SEARCH { DEPTH | BREADTH } FIRST BY expression [ ASC | DESC | USING operator ] [, ...] SET column_name ] [ CYCLE ( column_list ) SET column_name TO expression DEFAULT expression USING columm_name ]
The following "railroad diagrams" are generated using Ebnf2ps from the yacc grammar.
I have generated a yacc grammar from BNF in SQL99 spec using a python script and some manual editing.
This could be used as rough reference for writing the real one in backend/parser/parser.y.
queryExpression : optWithClause queryExpressionBody ; optWithClause: withClause | ; withClause : WITH optRecursive withList ; optRecursive : RECURSIVE | ; withList : withList withListElement | withListElement ; withListElement : queryName optWithColumnList AS '(' queryExpression ')' optSearchOrCycleClause ; optWithColumnList : '(' withColumnList ')' | ; optSearchOrCycleClause: optSearchClause optCycleClause ; optSearchClause: searchClause | ; optCycleClause: cycleClause | ; withColumnList : columnNameList ; searchClause : SEARCH recursiveSearchOrder SET sequenceColumn ; recursiveSearchOrder : DEPTH FIRST BY sortSpecificationList | BREADTH FIRST BY sortSpecificationList ; sequenceColumn : columnName ; sortSpecificationList : sortSpecification | sortSpecificationList ',' sortSpecification ; sortSpecification : sortKey optCollateClause orderingSpecification ; sortKey : valueExpression ; orderingSpecification : ASC | DESC | ; cycleClause : CYCLE cycleColumnList SET cycleMarkColumn TO cycleMarkValue DEFAULT non_cycleMarkValue USING pathColumn ; cycleColumnList : cycleColumnList "," cycleColumn | cycleColumn ; cycleColumn : columnName ; cycleMarkColumn : columnName ; pathColumn : columnName ; cycleMarkValue : valueExpression ; non_cycleMarkValue : valueExpression ;
<query expression> ::= [ <with clause> ] <query expression body> <with clause> ::= WITH [ RECURSIVE ] <with list> <with list> ::= <with list element> [ { <comma> <with list element> }... ] <with list element> ::= <query name> [ <left paren> <with column list> <right paren> ] AS <left paren> <query expression> <right paren> [ <search or cycle clause> ] <with column list> ::= <column name list> <search or cycle clause> ::= <search clause> | <cycle clause> | <search clause> <cycle clause> <search clause> ::= SEARCH <recursive search order> SET <sequence column> <recursive search order> ::= DEPTH FIRST BY <sort specification list> | BREADTH FIRST BY <sort specification list> <sequence column> ::= <column name> <cycle clause> ::= CYCLE <cycle column list> SET <cycle mark column> TO <cycle mark value> DEFAULT <non-cycle mark value> USING <path column> <cycle column list> ::= <cycle column> [ { <comma> <cycle column> }... ] <cycle column> ::= <column name> <cycle mark column> ::= <column name> <path column> ::= <column name> <cycle mark value> ::= <value expression> <non-cycle mark value> ::= <value expression>
This is the hard part ;)
The following could be studied for learning about ANSI/ISO SQL99/200x recursive queries
- Recursive queries are defined in section 7.12 of the ANSI/ISO SQL99 standard
- IBM DB2 uses similar syntax to SQL99 (ibm db2 syntax)
- Oracle uses very different syntax.