WHAT'S THIS

This is a patch which allows PgSQL to make hierarchical queries a la Oracle do.

(c) Evgen Potemkin 2002, < gppl at inbox dot ru >, entirely based on PostgreSQL (http://www.postgresql.org)
Patch itself distributed under GPL. No warranty of any kind is given, use it at your own risk.

INSTALLATION

tar xzf postgresql-7.x.tar.gz
patch -p0 < hier.diff
cd postgresql-7.x/
./configure
... so on

SYNOPSIS

#create table data (id int4, pnt int4, data varchar(20));

data:

+----+-----+-------------+
| id | pnt |    data     |
+----+-----+-------------+
| 0  | 0   | root        |
| 1  | 0   | (1 leaf l1) |
| 2  | 0   | (2 leaf l1) |
| 3  | 0   | (3 leaf l1) |
| 4  | 1   | (11 leaf l2)|
| 5  | 1   | (12 leaf l2)|
| 6  | 1   | (13 leaf l2)|
| 7  | 3   | (31 leaf l2)|
| 8  | 3   | (32 leaf l2)|
+----+-----+-------------+

# SELECT * FROM data CONNECT BY PRIOR id = pnt START WITH id=0;

output:

 id | pnt |    data     | _level_
----+-----+-------------+---------
 0  | 0   | root        | 1
 1  | 0   | (1 leaf l1) | 2
 4  | 1   | (11 leaf l2)| 3
 5  | 1   | (12 leaf l2)| 3
 6  | 1   | (13 leaf l2)| 3
 2  | 0   | (2 leaf l1) | 2
 3  | 0   | (3 leaf l1) | 2
 7  | 3   | (31 leaf l2)| 3
 8  | 3   | (32 leaf l2)| 3

DESCRIPTION

Hierarchical query.

Lets tree is like:

                          (root)
                        /   |    \
                      /     |      \
             (1 leaf l1) (2 leaf l1) (3 leaf l1)
            /    |    \                   |     \
          /      |      \                 |       \
(11 leaf l2) (12 leaf l2) (13 leaf l2) (31 leaf l2) (32 leaf l2)

so lets define hierarchical query as query which return us a set like:
+------------+
|root        |
|(1 leaf l1) |
|(11 leaf l2)|
|(12 leaf l2)|
|(13 leaf l2)|
|(2 leaf l1) |
|(3 leaf l1) |
|(31 leaf l2)|
|(32 leaf l2)|
+------------+

i.e. first is root,then first child of root, then first child of first child, if any, or second child otherwise, ... so on.

REASON.

Often hierarchical queries are made by adding special field which stores a position of a row in the tree, and then make "SELECT ... ORDER BY 'hier_position_field'" over the table. disability of such approach is that we can't sort leaves in some custom order.

This patch is based on internal PG's query processing and havn't such disadvantage.

SYNTAX.

SELECT ... FROM ... [ WHERE condition ] hier_clause
  [ HAVING condition [, ...]] [ ORDER BY ... ] [ LIMIT ... ] [ OFFSET ... ]

hier_clause: connect_clause start_with_clause
		| start_with_clause connect_clause
		| /* EMPTY */
		;
connect_clause: CONNECT BY PRIOR c_expr qual_Op c_expr
		| CONNECT BY c_expr qual_Op PRIOR c_expr
		;
start_with_clause: START WITH a_expr
		;

... means the same as usual SELECT
qual_Op is an operator.
c_expr is a column name or function call
expr is a WHERE-like expression
Warn! Aggregates can't be used with CONNECT BY clause.

RESULTS.

query return sets like discribed in synopsis. '_level_' is additional column which added only in case of hierarchical query. it means deep of row in the tree, starts from 1.

Difference with Oracle's hierarchical queries: WHERE clause evaluated BEFORE connecting. for qualifying rows after they been connected use HAVING.

MISC.

Subqueries, views and cursors are supported.
initdb is required
Feedback is welcome:)

CHANGES.

v 0.3

v 0.2

v 0.1