Commit a265b7f7 authored by Bruce Momjian's avatar Bruce Momjian

> Am Son, 2003-06-22 um 02.09 schrieb Joe Conway:

>>Sounds like all that's needed for your case. But to be complete, in
>>addition to changing tablefunc.c we'd have to:
>>1) come up with a new function call signature that makes sense and does
>>not cause backward compatibility problems for other people
>>2) make needed changes to tablefunc.sql.in
>>3) adjust the README.tablefunc appropriately
>>4) adjust the regression test for new functionality
>>5) be sure we don't break any of the old cases
>>
>>If you want to submit a complete patch, it would be gratefully accepted
>>-- for review at least ;-)
>
> Here's the patch, at least for steps 1-3

Nabil Sayegh
Joe Conway
parent 9ae69055
...@@ -4,6 +4,8 @@ ...@@ -4,6 +4,8 @@
* Sample to demonstrate C functions which return setof scalar * Sample to demonstrate C functions which return setof scalar
* and setof composite. * and setof composite.
* Joe Conway <mail@joeconway.com> * Joe Conway <mail@joeconway.com>
* And contributors:
* Nabil Sayegh <postgresql@e-trolley.de>
* *
* Copyright 2002 by PostgreSQL Global Development Group * Copyright 2002 by PostgreSQL Global Development Group
* *
...@@ -60,9 +62,11 @@ Installation: ...@@ -60,9 +62,11 @@ 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, connectby(text relname, text keyid_fld, text parent_keyid_fld
text start_with, int max_depth [, text branch_delim]) [, text orderby_fld], text start_with, int max_depth
[, text branch_delim])
- returns keyid, parent_keyid, level, and an optional branch string - returns keyid, parent_keyid, level, and an optional branch string
and an optional serial column for ordering siblings
- 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.
...@@ -452,13 +456,14 @@ AS ...@@ -452,13 +456,14 @@ AS
================================================================== ==================================================================
Name Name
connectby(text, text, text, text, int[, text]) - returns a set connectby(text, text, text[, text], text, text, int[, text]) - returns a set
representing a hierarchy (tree structure) representing a hierarchy (tree structure)
Synopsis Synopsis
connectby(text relname, text keyid_fld, text parent_keyid_fld, connectby(text relname, text keyid_fld, text parent_keyid_fld
text start_with, int max_depth [, text branch_delim]) [, text orderby_fld], text start_with, int max_depth
[, text branch_delim])
Inputs Inputs
...@@ -474,6 +479,11 @@ Inputs ...@@ -474,6 +479,11 @@ Inputs
Name of the key_parent field Name of the key_parent field
orderby_fld
If optional ordering of siblings is desired:
Name of the field to order siblings
start_with start_with
root value of the tree input as a text value regardless of keyid_fld type root value of the tree input as a text value regardless of keyid_fld type
...@@ -500,6 +510,16 @@ Outputs ...@@ -500,6 +510,16 @@ Outputs
SELECT * FROM connectby('connectby_tree', 'keyid', 'parent_keyid', 'row2', 0) SELECT * FROM connectby('connectby_tree', 'keyid', 'parent_keyid', 'row2', 0)
AS t(keyid text, parent_keyid text, level int); AS t(keyid text, parent_keyid text, level int);
- or -
SELECT * FROM connectby('connectby_tree', 'keyid', 'parent_keyid', 'pos', 'row2', 0, '~')
AS t(keyid text, parent_keyid text, level int, branch text, pos int);
- or -
SELECT * FROM connectby('connectby_tree', 'keyid', 'parent_keyid', 'pos', 'row2', 0)
AS t(keyid text, parent_keyid text, level int, pos int);
Notes Notes
...@@ -520,22 +540,25 @@ Notes ...@@ -520,22 +540,25 @@ Notes
5. The parameters representing table and field names must include double 5. The parameters representing table and field names must include double
quotes if the names are mixed-case or contain special characters. quotes if the names are mixed-case or contain special characters.
6. If sorting of siblings is desired, the orderby_fld input parameter *and*
a name for the resulting serial field (type INT32) in the query column
definition must be given.
Example usage Example usage
CREATE TABLE connectby_tree(keyid text, parent_keyid text); CREATE TABLE connectby_tree(keyid text, parent_keyid text, pos int);
INSERT INTO connectby_tree VALUES('row1',NULL); INSERT INTO connectby_tree VALUES('row1',NULL, 0);
INSERT INTO connectby_tree VALUES('row2','row1'); INSERT INTO connectby_tree VALUES('row2','row1', 0);
INSERT INTO connectby_tree VALUES('row3','row1'); INSERT INTO connectby_tree VALUES('row3','row1', 0);
INSERT INTO connectby_tree VALUES('row4','row2'); INSERT INTO connectby_tree VALUES('row4','row2', 1);
INSERT INTO connectby_tree VALUES('row5','row2'); INSERT INTO connectby_tree VALUES('row5','row2', 0);
INSERT INTO connectby_tree VALUES('row6','row4'); INSERT INTO connectby_tree VALUES('row6','row4', 0);
INSERT INTO connectby_tree VALUES('row7','row3'); INSERT INTO connectby_tree VALUES('row7','row3', 0);
INSERT INTO connectby_tree VALUES('row8','row6'); INSERT INTO connectby_tree VALUES('row8','row6', 0);
INSERT INTO connectby_tree VALUES('row9','row5'); INSERT INTO connectby_tree VALUES('row9','row5', 0);
-- with branch -- with branch, without orderby_fld
SELECT * FROM connectby('connectby_tree', 'keyid', 'parent_keyid', 'row2', 0, '~') SELECT * FROM connectby('connectby_tree', 'keyid', 'parent_keyid', 'row2', 0, '~')
AS t(keyid text, parent_keyid text, level int, branch text); AS t(keyid text, parent_keyid text, level int, branch text);
keyid | parent_keyid | level | branch keyid | parent_keyid | level | branch
...@@ -548,7 +571,7 @@ SELECT * FROM connectby('connectby_tree', 'keyid', 'parent_keyid', 'row2', 0, '~ ...@@ -548,7 +571,7 @@ SELECT * FROM connectby('connectby_tree', 'keyid', 'parent_keyid', 'row2', 0, '~
row9 | row5 | 2 | row2~row5~row9 row9 | row5 | 2 | row2~row5~row9
(6 rows) (6 rows)
-- without branch -- without branch, without orderby_fld
SELECT * FROM connectby('connectby_tree', 'keyid', 'parent_keyid', 'row2', 0) SELECT * FROM connectby('connectby_tree', 'keyid', 'parent_keyid', 'row2', 0)
AS t(keyid text, parent_keyid text, level int); AS t(keyid text, parent_keyid text, level int);
keyid | parent_keyid | level keyid | parent_keyid | level
...@@ -561,6 +584,32 @@ SELECT * FROM connectby('connectby_tree', 'keyid', 'parent_keyid', 'row2', 0) ...@@ -561,6 +584,32 @@ SELECT * FROM connectby('connectby_tree', 'keyid', 'parent_keyid', 'row2', 0)
row9 | row5 | 2 row9 | row5 | 2
(6 rows) (6 rows)
-- with branch, with orderby_fld (notice that row5 comes before row4)
SELECT * FROM connectby('connectby_tree', 'keyid', 'parent_keyid', 'pos', 'row2', 0, '~')
AS t(keyid text, parent_keyid text, level int, branch text, pos int) ORDER BY t.pos;
keyid | parent_keyid | level | branch | pos
-------+--------------+-------+---------------------+-----
row2 | | 0 | row2 | 1
row5 | row2 | 1 | row2~row5 | 2
row9 | row5 | 2 | row2~row5~row9 | 3
row4 | row2 | 1 | row2~row4 | 4
row6 | row4 | 2 | row2~row4~row6 | 5
row8 | row6 | 3 | row2~row4~row6~row8 | 6
(6 rows)
-- without branch, with orderby_fld (notice that row5 comes before row4)
SELECT * FROM connectby('connectby_tree', 'keyid', 'parent_keyid', 'pos', 'row2', 0)
AS t(keyid text, parent_keyid text, level int, pos int) ORDER BY t.pos;
keyid | parent_keyid | level | pos
-------+--------------+-------+-----
row2 | | 0 | 1
row5 | row2 | 1 | 2
row9 | row5 | 2 | 3
row4 | row2 | 1 | 4
row6 | row4 | 2 | 5
row8 | row6 | 3 | 6
(6 rows)
================================================================== ==================================================================
-- Joe Conway -- Joe Conway
row1 \N row1 \N 0
row2 row1 row2 row1 0
row3 row1 row3 row1 0
row4 row2 row4 row2 1
row5 row2 row5 row2 0
row6 row4 row6 row4 0
row7 row3 row7 row3 0
row8 row6 row8 row6 0
row9 row5 row9 row5 0
...@@ -197,9 +197,9 @@ ERROR: provided "categories" SQL must return 1 column of at least one row ...@@ -197,9 +197,9 @@ ERROR: provided "categories" SQL must return 1 column of at least one row
-- connectby -- connectby
-- --
-- test connectby with text based hierarchy -- test connectby with text based hierarchy
CREATE TABLE connectby_text(keyid text, parent_keyid text); CREATE TABLE connectby_text(keyid text, parent_keyid text, pos int);
\copy connectby_text from 'data/connectby_text.data' \copy connectby_text from 'data/connectby_text.data'
-- with branch -- with branch, without orderby
SELECT * FROM connectby('connectby_text', 'keyid', 'parent_keyid', 'row2', 0, '~') AS t(keyid text, parent_keyid text, level int, branch text); SELECT * FROM connectby('connectby_text', 'keyid', 'parent_keyid', 'row2', 0, '~') AS t(keyid text, parent_keyid text, level int, branch text);
keyid | parent_keyid | level | branch keyid | parent_keyid | level | branch
-------+--------------+-------+--------------------- -------+--------------+-------+---------------------
...@@ -211,7 +211,7 @@ SELECT * FROM connectby('connectby_text', 'keyid', 'parent_keyid', 'row2', 0, '~ ...@@ -211,7 +211,7 @@ SELECT * FROM connectby('connectby_text', 'keyid', 'parent_keyid', 'row2', 0, '~
row9 | row5 | 2 | row2~row5~row9 row9 | row5 | 2 | row2~row5~row9
(6 rows) (6 rows)
-- without branch -- without branch, without orderby
SELECT * FROM connectby('connectby_text', 'keyid', 'parent_keyid', 'row2', 0) AS t(keyid text, parent_keyid text, level int); SELECT * FROM connectby('connectby_text', 'keyid', 'parent_keyid', 'row2', 0) AS t(keyid text, parent_keyid text, level int);
keyid | parent_keyid | level keyid | parent_keyid | level
-------+--------------+------- -------+--------------+-------
...@@ -223,6 +223,30 @@ SELECT * FROM connectby('connectby_text', 'keyid', 'parent_keyid', 'row2', 0) AS ...@@ -223,6 +223,30 @@ SELECT * FROM connectby('connectby_text', 'keyid', 'parent_keyid', 'row2', 0) AS
row9 | row5 | 2 row9 | row5 | 2
(6 rows) (6 rows)
-- with branch, with orderby
SELECT * FROM connectby('connectby_text', 'keyid', 'parent_keyid', 'pos', 'row2', 0, '~') AS t(keyid text, parent_keyid text, level int, branch text, pos int) ORDER BY t.pos;
keyid | parent_keyid | level | branch | pos
-------+--------------+-------+---------------------+-----
row2 | | 0 | row2 | 1
row5 | row2 | 1 | row2~row5 | 2
row9 | row5 | 2 | row2~row5~row9 | 3
row4 | row2 | 1 | row2~row4 | 4
row6 | row4 | 2 | row2~row4~row6 | 5
row8 | row6 | 3 | row2~row4~row6~row8 | 6
(6 rows)
-- without branch, with orderby
SELECT * FROM connectby('connectby_text', 'keyid', 'parent_keyid', 'pos', 'row2', 0) AS t(keyid text, parent_keyid text, level int, pos int) ORDER BY t.pos;
keyid | parent_keyid | level | pos
-------+--------------+-------+-----
row2 | | 0 | 1
row5 | row2 | 1 | 2
row9 | row5 | 2 | 3
row4 | row2 | 1 | 4
row6 | row4 | 2 | 5
row8 | row6 | 3 | 6
(6 rows)
-- test connectby with int based hierarchy -- test connectby with int based hierarchy
CREATE TABLE connectby_int(keyid int, parent_keyid int); CREATE TABLE connectby_int(keyid int, parent_keyid int);
\copy connectby_int from 'data/connectby_int.data' \copy connectby_int from 'data/connectby_int.data'
......
...@@ -94,15 +94,21 @@ AS c(rowid text, rowdt timestamp, temperature int4, test_result text, test_start ...@@ -94,15 +94,21 @@ AS c(rowid text, rowdt timestamp, temperature int4, test_result text, test_start
-- --
-- test connectby with text based hierarchy -- test connectby with text based hierarchy
CREATE TABLE connectby_text(keyid text, parent_keyid text); CREATE TABLE connectby_text(keyid text, parent_keyid text, pos int);
\copy connectby_text from 'data/connectby_text.data' \copy connectby_text from 'data/connectby_text.data'
-- with branch -- with branch, without orderby
SELECT * FROM connectby('connectby_text', 'keyid', 'parent_keyid', 'row2', 0, '~') AS t(keyid text, parent_keyid text, level int, branch text); SELECT * FROM connectby('connectby_text', 'keyid', 'parent_keyid', 'row2', 0, '~') AS t(keyid text, parent_keyid text, level int, branch text);
-- without branch -- without branch, without orderby
SELECT * FROM connectby('connectby_text', 'keyid', 'parent_keyid', 'row2', 0) AS t(keyid text, parent_keyid text, level int); SELECT * FROM connectby('connectby_text', 'keyid', 'parent_keyid', 'row2', 0) AS t(keyid text, parent_keyid text, level int);
-- with branch, with orderby
SELECT * FROM connectby('connectby_text', 'keyid', 'parent_keyid', 'pos', 'row2', 0, '~') AS t(keyid text, parent_keyid text, level int, branch text, pos int) ORDER BY t.pos;
-- without branch, with orderby
SELECT * FROM connectby('connectby_text', 'keyid', 'parent_keyid', 'pos', 'row2', 0) AS t(keyid text, parent_keyid text, level int, pos int) ORDER BY t.pos;
-- test connectby with int based hierarchy -- test connectby with int based hierarchy
CREATE TABLE connectby_int(keyid int, parent_keyid int); CREATE TABLE connectby_int(keyid int, parent_keyid int);
\copy connectby_int from 'data/connectby_int.data' \copy connectby_int from 'data/connectby_int.data'
......
This diff is collapsed.
...@@ -4,6 +4,8 @@ ...@@ -4,6 +4,8 @@
* Sample to demonstrate C functions which return setof scalar * Sample to demonstrate C functions which return setof scalar
* and setof composite. * and setof composite.
* Joe Conway <mail@joeconway.com> * Joe Conway <mail@joeconway.com>
* And contributors:
* Nabil Sayegh <postgresql@e-trolley.de>
* *
* Copyright 2002 by PostgreSQL Global Development Group * Copyright 2002 by PostgreSQL Global Development Group
* *
...@@ -36,5 +38,6 @@ extern Datum normal_rand(PG_FUNCTION_ARGS); ...@@ -36,5 +38,6 @@ extern Datum normal_rand(PG_FUNCTION_ARGS);
extern Datum crosstab(PG_FUNCTION_ARGS); extern Datum crosstab(PG_FUNCTION_ARGS);
extern Datum crosstab_hash(PG_FUNCTION_ARGS); extern Datum crosstab_hash(PG_FUNCTION_ARGS);
extern Datum connectby_text(PG_FUNCTION_ARGS); extern Datum connectby_text(PG_FUNCTION_ARGS);
extern Datum connectby_text_serial(PG_FUNCTION_ARGS);
#endif /* TABLEFUNC_H */ #endif /* TABLEFUNC_H */
...@@ -64,3 +64,15 @@ CREATE OR REPLACE FUNCTION connectby(text,text,text,text,int) ...@@ -64,3 +64,15 @@ CREATE OR REPLACE FUNCTION connectby(text,text,text,text,int)
RETURNS setof record RETURNS setof record
AS 'MODULE_PATHNAME','connectby_text' AS 'MODULE_PATHNAME','connectby_text'
LANGUAGE 'C' STABLE STRICT; LANGUAGE 'C' STABLE STRICT;
-- These 2 take the name of a field to ORDER BY as 4th arg (for sorting siblings)
CREATE OR REPLACE FUNCTION connectby(text,text,text,text,text,int,text)
RETURNS setof record
AS 'MODULE_PATHNAME','connectby_text_serial'
LANGUAGE 'C' STABLE STRICT;
CREATE OR REPLACE FUNCTION connectby(text,text,text,text,text,int)
RETURNS setof record
AS 'MODULE_PATHNAME','connectby_text_serial'
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