完善树函数

This commit is contained in:
2024-03-17 12:46:21 +08:00
parent cbec3d5630
commit 559be98b29
5 changed files with 111 additions and 0 deletions

View File

@@ -7,4 +7,6 @@ import lombok.Data;
@Data
public class DepartmentDto extends OrgCommonDto {
private String parent;
private Integer empCount;
}

View File

@@ -8,6 +8,7 @@ import java.util.List;
@Data
public class DepartmentTreeDto extends OrgCommonDto {
private Integer empCount;
private String parent;
private List<DepartmentTreeDto> children;
}

View File

@@ -11,6 +11,7 @@ import lombok.Getter;
import lombok.Setter;
import org.hibernate.annotations.Comment;
import org.hibernate.annotations.Formula;
import java.util.List;
@@ -20,6 +21,8 @@ import java.util.List;
@Setter
public class DepartmentEntity extends OrgCommonEntity {
@Formula("(select count(*) from t_employee e where e.department_id = any(self_and_children_ids('t_department', id)))")
private Integer empCount;
@OneToMany(mappedBy = "parent", cascade = CascadeType.ALL)
private List<DepartmentEntity> children;

View File

@@ -3,6 +3,7 @@ package cn.lihongjie.coal.spring.config;
import cn.lihongjie.coal.annotation.HyperTable;
import org.hibernate.boot.Metadata;
import org.hibernate.boot.model.FunctionContributions;
import org.hibernate.boot.model.relational.SqlStringGenerationContext;
import org.hibernate.dialect.PostgreSQLDialect;
import org.hibernate.mapping.PersistentClass;
@@ -16,6 +17,13 @@ import java.util.stream.Collectors;
public class MyPostgreSQLDialect extends PostgreSQLDialect {
@Override
public void initializeFunctionRegistry(FunctionContributions functionContributions) {
super.initializeFunctionRegistry(functionContributions);
functionContributions.getFunctionRegistry().registerNamed("self_and_children_ids");
functionContributions.getFunctionRegistry().registerNamed("self_and_parent_ids");
}
@Override
protected String columnType(int sqlTypeCode) {
if (sqlTypeCode == SqlTypes.VARCHAR) {

View File

@@ -0,0 +1,97 @@
drop function if exists selfAndChildrenIds;
drop function if exists selfAndParentIds;
create or replace function self_and_children_ids(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 self_and_parent_ids(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
;