添加树函数

This commit is contained in:
2024-03-17 11:05:58 +08:00
parent 4303fa40d8
commit 9b9d2d7ce1

View File

@@ -0,0 +1,93 @@
create or replace function selfAndChildrenIds(tb text, id text, includeSelf bool = true) returns text[] AS
$$
declare
ans text[];
sql text;
text1 text;
begin
-- logic
if includeSelf then
text1 = 'id' ;
else
text1 = 'parent_id' ;
end if;
sql = 'with recursive tmp as (select id
from ' ||
tb ||
'
where ' ||
text1 ||
' = $1
union all
select ' ||
tb ||
'.id
from ' ||
tb ||
'
inner join tmp on ' ||
tb ||
'.parent_id = tmp.id)
select array_agg(id)
from tmp';
execute sql into ans using id;
return ans;
end
$$ language plpgsql
;
create or replace function selfAndParentIds(tb text, id text, includeSelf bool = true) returns text[] AS
$$
declare
ans text[];
sql text;
begin
-- logic
sql = 'with recursive tmp as (select id,parent_id
from ' ||
tb ||
'
where ' ||
'id = $1
union all
select ' ||
tb ||
'.id, ' || tb || '.parent_id
from ' ||
tb ||
'
inner join tmp on ' ||
tb ||
'.id = tmp.parent_id)
select array_agg(id)
from tmp ';
if not includeSelf
then
sql = sql || ' where id != $1';
end if;
execute sql into ans using id;
return ans;
end
$$ language plpgsql
;