Commit 6aa4482f authored by Bruce Momjian's avatar Bruce Momjian

Attached is an update to contrib/tablefunc. It introduces a new

function, connectby(), which can serve as a reference implementation for

the changes made in the last few days -- namely the ability of a
function to return an entire tuplestore, and the ability of a function
to make use of the query provided "expected" tuple description.

Description:

   connectby(text relname, text keyid_fld, text parent_keyid_fld,
     text start_with, int max_depth [, text branch_delim])
   - returns keyid, parent_keyid, level, and an optional branch string
   - requires anonymous composite type syntax in the FROM clause. See
     the instructions in the documentation below.

Joe Conway
parent 9fd842c4
...@@ -60,6 +60,12 @@ Installation: ...@@ -60,6 +60,12 @@ Installation:
- requires anonymous composite type syntax in the FROM clause. See - requires anonymous composite type syntax in the FROM clause. See
the instructions in the documentation below. the instructions in the documentation below.
connectby(text relname, text keyid_fld, text parent_keyid_fld,
text start_with, int max_depth [, text branch_delim])
- returns keyid, parent_keyid, level, and an optional branch string
- requires anonymous composite type syntax in the FROM clause. See
the instructions in the documentation below.
Documentation Documentation
================================================================== ==================================================================
Name Name
...@@ -324,6 +330,109 @@ AS ct(row_name text, category_1 text, category_2 text, category_3 text); ...@@ -324,6 +330,109 @@ AS ct(row_name text, category_1 text, category_2 text, category_3 text);
test2 | val6 | val7 | test2 | val6 | val7 |
(2 rows) (2 rows)
==================================================================
Name
connectby(text, text, text, text, int[, text]) - returns a set
representing a hierarchy (tree structure)
Synopsis
connectby(text relname, text keyid_fld, text parent_keyid_fld,
text start_with, int max_depth [, text branch_delim])
Inputs
relname
Name of the source relation
keyid_fld
Name of the key field
parent_keyid_fld
Name of the key_parent field
start_with
root value of the tree input as a text value regardless of keyid_fld type
max_depth
zero (0) for unlimited depth, otherwise restrict level to this depth
branch_delim
if optional branch value is desired, this string is used as the delimiter
Outputs
Returns setof record, which must defined with a column definition
in the FROM clause of the SELECT statement, e.g.:
SELECT * FROM connectby('connectby_tree', 'keyid', 'parent_keyid', 'row2', 0, '~')
AS t(keyid text, parent_keyid text, level int, branch text);
- or -
SELECT * FROM connectby('connectby_tree', 'keyid', 'parent_keyid', 'row2', 0)
AS t(keyid text, parent_keyid text, level int);
Notes
1. keyid and parent_keyid must be the same data type
2. The column definition *must* include a third column of type INT4 for
the level value output
3. If the branch field is not desired, omit both the branch_delim input
parameter *and* the branch field in the query column definition
4. If the branch field is desired, it must be the forth column in the query
column definition, and it must be type TEXT
Example usage
CREATE TABLE connectby_tree(keyid text, parent_keyid text);
INSERT INTO connectby_tree VALUES('row1',NULL);
INSERT INTO connectby_tree VALUES('row2','row1');
INSERT INTO connectby_tree VALUES('row3','row1');
INSERT INTO connectby_tree VALUES('row4','row2');
INSERT INTO connectby_tree VALUES('row5','row2');
INSERT INTO connectby_tree VALUES('row6','row4');
INSERT INTO connectby_tree VALUES('row7','row3');
INSERT INTO connectby_tree VALUES('row8','row6');
INSERT INTO connectby_tree VALUES('row9','row5');
-- with branch
SELECT * FROM connectby('connectby_tree', 'keyid', 'parent_keyid', 'row2', 0, '~')
AS t(keyid text, parent_keyid text, level int, branch text);
keyid | parent_keyid | level | branch
-------+--------------+-------+---------------------
row2 | | 0 | row2
row4 | row2 | 1 | row2~row4
row6 | row4 | 2 | row2~row4~row6
row8 | row6 | 3 | row2~row4~row6~row8
row5 | row2 | 1 | row2~row5
row9 | row5 | 2 | row2~row5~row9
(6 rows)
-- without branch
SELECT * FROM connectby('connectby_tree', 'keyid', 'parent_keyid', 'row2', 0)
AS t(keyid text, parent_keyid text, level int);
keyid | parent_keyid | level
-------+--------------+-------
row2 | | 0
row4 | row2 | 1
row6 | row4 | 2
row8 | row6 | 3
row5 | row2 | 1
row9 | row5 | 2
(6 rows)
================================================================== ==================================================================
-- Joe Conway -- Joe Conway
--
-- show_all_settings()
--
SELECT * FROM show_all_settings();
-- --
-- normal_rand() -- normal_rand()
-- --
...@@ -47,3 +42,44 @@ select * from crosstab4('select rowid, attribute, value from ct where rowclass = ...@@ -47,3 +42,44 @@ select * from crosstab4('select rowid, attribute, value from ct where rowclass =
select * from crosstab('select rowid, attribute, value from ct where rowclass = ''group1'' order by 1,2;', 2) as c(rowid text, att1 text, att2 text); select * from crosstab('select rowid, attribute, value from ct where rowclass = ''group1'' order by 1,2;', 2) as c(rowid text, att1 text, att2 text);
select * from crosstab('select rowid, attribute, value from ct where rowclass = ''group1'' order by 1,2;', 3) as c(rowid text, att1 text, att2 text, att3 text); select * from crosstab('select rowid, attribute, value from ct where rowclass = ''group1'' order by 1,2;', 3) as c(rowid text, att1 text, att2 text, att3 text);
select * from crosstab('select rowid, attribute, value from ct where rowclass = ''group1'' order by 1,2;', 4) as c(rowid text, att1 text, att2 text, att3 text, att4 text); select * from crosstab('select rowid, attribute, value from ct where rowclass = ''group1'' order by 1,2;', 4) as c(rowid text, att1 text, att2 text, att3 text, att4 text);
-- test connectby with text based hierarchy
DROP TABLE connectby_tree;
CREATE TABLE connectby_tree(keyid text, parent_keyid text);
INSERT INTO connectby_tree VALUES('row1',NULL);
INSERT INTO connectby_tree VALUES('row2','row1');
INSERT INTO connectby_tree VALUES('row3','row1');
INSERT INTO connectby_tree VALUES('row4','row2');
INSERT INTO connectby_tree VALUES('row5','row2');
INSERT INTO connectby_tree VALUES('row6','row4');
INSERT INTO connectby_tree VALUES('row7','row3');
INSERT INTO connectby_tree VALUES('row8','row6');
INSERT INTO connectby_tree VALUES('row9','row5');
-- with branch
SELECT * FROM connectby('connectby_tree', 'keyid', 'parent_keyid', 'row2', 0, '~') AS t(keyid text, parent_keyid text, level int, branch text);
-- without branch
SELECT * FROM connectby('connectby_tree', 'keyid', 'parent_keyid', 'row2', 0) AS t(keyid text, parent_keyid text, level int);
-- test connectby with int based hierarchy
DROP TABLE connectby_tree;
CREATE TABLE connectby_tree(keyid int, parent_keyid int);
INSERT INTO connectby_tree VALUES(1,NULL);
INSERT INTO connectby_tree VALUES(2,1);
INSERT INTO connectby_tree VALUES(3,1);
INSERT INTO connectby_tree VALUES(4,2);
INSERT INTO connectby_tree VALUES(5,2);
INSERT INTO connectby_tree VALUES(6,4);
INSERT INTO connectby_tree VALUES(7,3);
INSERT INTO connectby_tree VALUES(8,6);
INSERT INTO connectby_tree VALUES(9,5);
-- with branch
SELECT * FROM connectby('connectby_tree', 'keyid', 'parent_keyid', '2', 0, '~') AS t(keyid int, parent_keyid int, level int, branch text);
-- without branch
SELECT * FROM connectby('connectby_tree', 'keyid', 'parent_keyid', '2', 0) AS t(keyid int, parent_keyid int, level int);
This diff is collapsed.
...@@ -34,5 +34,6 @@ ...@@ -34,5 +34,6 @@
*/ */
extern Datum normal_rand(PG_FUNCTION_ARGS); extern Datum normal_rand(PG_FUNCTION_ARGS);
extern Datum crosstab(PG_FUNCTION_ARGS); extern Datum crosstab(PG_FUNCTION_ARGS);
extern Datum connectby_text(PG_FUNCTION_ARGS);
#endif /* TABLEFUNC_H */ #endif /* TABLEFUNC_H */
...@@ -37,4 +37,12 @@ CREATE OR REPLACE FUNCTION crosstab4(text) ...@@ -37,4 +37,12 @@ CREATE OR REPLACE FUNCTION crosstab4(text)
CREATE OR REPLACE FUNCTION crosstab(text,int) CREATE OR REPLACE FUNCTION crosstab(text,int)
RETURNS setof record RETURNS setof record
AS 'MODULE_PATHNAME','crosstab' LANGUAGE 'c' STABLE STRICT; AS 'MODULE_PATHNAME','crosstab' LANGUAGE 'c' STABLE STRICT;
\ No newline at end of file
CREATE OR REPLACE FUNCTION connectby(text,text,text,text,int,text)
RETURNS setof record
AS 'MODULE_PATHNAME','connectby_text' LANGUAGE 'c' STABLE STRICT;
CREATE OR REPLACE FUNCTION connectby(text,text,text,text,int)
RETURNS setof record
AS 'MODULE_PATHNAME','connectby_text' LANGUAGE 'c' STABLE STRICT;
Markdown is supported
0% or
You are about to add 0 people to the discussion. Proceed with caution.
Finish editing this message first!
Please register or to comment