Обсуждение: connectby questions

Поиск
Список
Период
Сортировка

connectby questions

От
Dan Langille
Дата:
I just installed 7.3rc1 and added contrib/tablefunc.  I am able to get the
example in the README document to work.  I am having trouble understanding
how to get my real data to behave.

The table is:

freshports=# \d element                               Table "public.element"      Column        |     Type     |
           Modifiers
 
---------------------+--------------+--------------------------------------------------id                  | integer
 | not null default
 
nextval('element_id_seq'::text)name                | text         | not nullparent_id           | integer
|directory_file_flag| character(1) | not nullstatus              | character(1) | not null
 

I have been able to get simple examples to work:

freshports=# select id, parent_id from connectby('element', 'id',
'parent_id', '104503', 0) as t(id int, parent_id int, level int);  id   | parent_id
--------+-----------104503 |104504 |    104503104505 |    104503
(3 rows)

Why does level not appear here?  I see a similar problem with this query:

freshports=# select id, parent_id from connectby('element', 'id',
'parent_id', '104503', 0, '/') as t(id int, parent_id int, level int,
branch text);  id   | parent_id
--------+-----------104503 |104504 |    104503104505 |    104503
(3 rows)

Here is the actual data for the above nodes:

freshports=# select * from element where id in (104503, 104504, 104505);  id   |     name     | parent_id |
directory_file_flag| status
 
--------+--------------+-----------+---------------------+--------104503 | multimedia   |     77344 | D
 | A104504 | Makefile     |    104503 | F                   | A104505 | chapter.sgml |    104503 | F
|A
 
(3 rows)

What I would like to include in the output is all of the above fields.
But I can't seem to get that to work:

freshports=# select id, parent_id, name from connectby('element', 'id',
'parent_id', '104503', 0, '/') ast(id int, parent_id int, level int, branch text, name text);
ERROR:  Query-specified return tuple not valid for Connectby: wrong number
of columns

I was able to do this with a view:
freshports=# create view simple_element as select id, parent_id from
element;
CREATE VIEW

freshports=# select * from connectby('simple_element', 'id', 'parent_id',
'104503', 0, '/') as t(id int,
parent_id int, level int, branch text);  id   | parent_id | level |    branch
--------+-----------+-------+---------------104503 |           |     0 | 104503104504 |    104503 |     1 |
104503/104504104505|    104503 |     1 | 104503/104505
 
(3 rows)

Whis is expected given what I see in the README.

But there doesn't seem to be any way to get the name field out:

freshports=# drop view simple_element;
DROP VIEW
freshports=# create view simple_element as select id, parent_id, name from
element;
CREATE VIEW
freshports=# select * from connectby('simple_element', 'id', 'parent_id',
'104503', 0, '/') as t(id int,
parent_id int, level int, branch text);  id   | parent_id | level |    branch
--------+-----------+-------+---------------104503 |           |     0 | 104503104504 |    104503 |     1 |
104503/104504104505|    104503 |     1 | 104503/104505
 
(3 rows)

freshports=# select * from connectby('simple_element', 'id', 'parent_id',
'104503', 0, '/') as t(id int, parent_id int, level int, branch text, name
text);
ERROR:  Query-specified return tuple not valid for Connectby: wrong number
of columns
freshports=#


I hope it's just that it's late and I'm missing something.  Cheers.




Re: connectby questions

От
Dan Langille
Дата:
On Fri, 22 Nov 2002, Dan Langille wrote:

> Here is the actual data for the above nodes:
>
> freshports=# select * from element where id in (104503, 104504, 104505);
>    id   |     name     | parent_id | directory_file_flag | status
> --------+--------------+-----------+---------------------+--------
>  104503 | multimedia   |     77344 | D                   | A
>  104504 | Makefile     |    104503 | F                   | A
>  104505 | chapter.sgml |    104503 | F                   | A
> (3 rows)
>
> What I would like to include in the output is all of the above fields.

DOH!  Use a join stupid!

freshports=# select t.*, tt.name
freshports-# from connectby('simple_element', 'id', 'parent_id', '104503',
0, '/')
freshports-#         as t(id int, parent_id int, level int, branch text),
element tt
freshports-# where t.id = tt.id;  id   | parent_id | level |    branch     |     name
--------+-----------+-------+---------------+--------------104503 |           |     0 | 104503        |
multimedia104504|    104503 |     1 | 104503/104504 | Makefile104505 |    104503 |     1 | 104503/104505 |
chapter.sgml
(3 rows)


Ok, that works.  But I have two issues:

1 - speed:  That join takes 7 seconds:

freshports=# explain analyze
freshports-# select t.*, tt.name
freshports-# from connectby('simple_element', 'id', 'parent_id', '104503',
0, '/
')
freshports-#         as t(id int, parent_id int, level int, branch text),
elemen
t tt
freshports-# where t.id = tt.id;                                                                 QUERY
PLAN

--------------------------------------------------------------------------------
--------------------------------------------------------------Merge Join  (cost=62.33..3050.43 rows=1000 width=60)
(actual
time=7420.23..7421
.03 rows=3 loops=1)  Merge Cond: ("outer".id = "inner".id)  ->  Index Scan using element_pkey on element tt
(cost=0.00..2708.97
rows=104
649 width=16) (actual time=1.69..5933.32 rows=104505 loops=1)  ->  Sort  (cost=62.33..64.83 rows=1000 width=44)
(actual
time=10.84..10.87 ro
ws=3 loops=1)        Sort Key: t.id        ->  Function Scan on connectby t  (cost=0.00..12.50 rows=1000
width=44)(actual time=10.12..10.17 rows=3 loops=1)Total runtime: 7421.78 msec
(7 rows)

freshports=#

2 - What I really want in the output is the branch defined by the name
fields, not by the id fields (e.g. instead of 104503/104504, show
multimedia/Makefile.



For what its worth, I did populate my test database with the full pathname
field, maintained by triggers.  However, the initial population of that
data took 160 minutes... Luckily, the tiggers are there as constraints (of
a sort) rather than actually used to cascade changes.  In practice, nodes
do not get renamed in my application.

Cheers