You cannot select more than 25 topics Topics must start with a letter or number, can include dashes ('-') and can be up to 35 characters long.
weaver-hrm-organization/docs/脚本/Oracle/组织架构图触发器.sql

397 lines
18 KiB
PL/PgSQL

create or replace trigger HrmCompany_ed before update on HrmCompany FOR EACH ROW
declare
vleader int;
vleaderimg varchar2(255);
vleadername varchar2(100);
vleaderjobid int;
vleaderjob varchar2(255);
vleaderlv varchar2(100);
vleaderst varchar2(100);
vdatebegin date;
vplan int;
vonjob int;
begin
if :new.companyname!=:old.companyname then
select to_number(fvalue) into vleader from jcl_info where id=1;
select messagerurl,lastname,jobtitle into vleaderimg,vleadername,vleaderjobid
from hrmresource where id=vleader;
select jobtitlemark into vleaderjob from hrmjobtitles where id=vleaderjobid;
select nvl(field100008,''),nvl(field100007,'') into vleaderst,vleaderlv from cus_fielddata
where scope='HrmCustomFieldByInfoType' and scopeid=3 and id=vleader;
vdatebegin:=sysdate;
select sum(nvl(staff_num,0)) into vplan from JCL_ORG_STAFF
where plan_id in (select id from JCL_ORG_STAFFPLAN where time_start<=vdatebegin and time_end>=vdatebegin);
select count(1) into vonjob from hrmresource where status<=3;
delete from jcl_org_map where fobjid=0 and fdatebegin=vdatebegin;
update jcl_org_map set fdateend=vdatebegin-1 where fobjid=0 and fdateend>vdatebegin;
insert into jcl_org_map
(id,ftype,fobjid,fecid,Uuid,fclass,fclassname,fnumber,fname,fleader,fleaderimg,
fleadername,fleaderjobid,fleaderjob,fleaderlv,fleaderst,fparentid,fobjparentid,
fplan,fonjob,fisvitual,fdatebegin,fdateend)
values
(0,0,0,:new.id,:new.uuid,0,'行政维度','00',:new.companyname,vleader,vleaderimg,
vleadername,vleaderjobid,vleaderjob,vleaderlv,vleaderst,-1,0,
vplan,vonjob,0,vdatebegin,to_date('2099-12-31','yyyy-mm-dd'));
end if;
end;
create or replace trigger JCL_ORG_COMP_ed after insert or update on JCL_ORG_COMP FOR EACH ROW
declare
vdatebegin date;
vecid int;
vleaderimg varchar2(255);
vleadername varchar2(100);
vleaderjobid int;
vleaderjob varchar2(255);
vleaderlv varchar2(100);
vleaderst varchar2(100);
vparentid int;
vobjparentid int;
vplan int;
vonjob int;
begin
if :new.comp_name!=:old.comp_name or :new.comp_principal!=:old.comp_principal or :new.parent_company!=:old.parent_company
or :new.forbidden_tag!=:old.forbidden_tag or :new.DELETE_TYPE!=:old.DELETE_TYPE then
vdatebegin:=sysdate;
vparentid:=nvl(:new.parent_company,0);
vobjparentid:=nvl(:new.parent_company,0);
select id into vecid from HrmSubCompany where uuid=:new.uuid;
select messagerurl,lastname,jobtitle into vleaderimg,vleadername,vleaderjobid from hrmresource where id=:new.comp_principal;
select jobtitlemark into vleaderjob from hrmjobtitles where id=vleaderjobid;
select nvl(field100008,''),nvl(field100007,'') into vleaderst,vleaderlv from cus_fielddata
where scope='HrmCustomFieldByInfoType' and scopeid=3 and id=:new.comp_principal;
select sum(nvl(staff_num,0)) into vplan from JCL_ORG_STAFF
where plan_id in (select id from JCL_ORG_STAFFPLAN where time_start<=vdatebegin and time_end>=vdatebegin) and comp_id=:new.id;
select count(1) into vonjob from hrmresource where status<=3 and subcompanyid1=vecid;
delete from jcl_org_map where ftype=1 and fobjid=:new.id and fdatebegin=vdatebegin;
update jcl_org_map set fdateend=vdatebegin-1 where ftype=1 and fobjid=:new.id and fdateend>vdatebegin;
if nvl(:new.DELETE_TYPE,0)=0 and nvl(:new.forbidden_tag,0)=0 then
insert into jcl_org_map
(id,ftype,fobjid,fecid,uuid,fclass,fclassname,fnumber,fname,fleader,fleaderimg,
fleadername,fleaderjobid,fleaderjob,fleaderlv,fleaderst,fparentid,fobjparentid,
fplan,fonjob,fisvitual,fdatebegin,fdateend)
values
(:new.id,1,:new.id,vecid,:new.uuid,0,'行政维度',:new.comp_no,:new.comp_name,:new.comp_principal,
vleaderimg,vleadername,vleaderjobid,vleaderjob,vleaderlv,vleaderst,vparentid,vobjparentid,
vplan,vonjob,0,vdatebegin,to_date('2099-12-31','yyyy-mm-dd'));
end if;
end if;
end;
create or replace trigger JCL_ORG_dept_ed after insert or update on JCL_ORG_dept FOR EACH ROW
declare
st int;
vdatebegin date;
vparentid int;
vobjparentid int;
vecid int;
vleaderimg VARCHAR2(200);
vleadername VARCHAR2(200);
veaderjobid int;
vleaderjob VARCHAR2(255);
vleaderst VARCHAR2(255);
vleaderlv VARCHAR2(255);
vplan int;
vonjob int;
begin
if :new.dept_name!=:old.dept_name or :new.dept_principal!=:old.dept_principal or :new.parent_comp!=:old.parent_comp
or :new.parent_dept!=:old.parent_dept or :new.forbidden_tag!=:old.forbidden_tag or :new.DELETE_TYPE!=:old.DELETE_TYPE then
st:=100000000;
vdatebegin:=sysdate;
if :new.parent_dept=0 then
vparentid:=:new.parent_comp;
else
vparentid:=:new.parent_dept+st;
end if;
if nvl(:new.parent_dept,0)=0 then
vobjparentid:=:new.parent_comp;
else
vobjparentid:=:new.parent_dept+st;
end if;
select id into vecid from HrmDepartment where uuid=:new.uuid;
select messagerurl,lastname,jobtitle into vleaderimg,vleadername,veaderjobid
from hrmresource where id=:new.dept_principal;
select jobtitlemark into vleaderjob from hrmjobtitles where id=:new.dept_principal;
select nvl(field100008,''),nvl(field100007,'') into vleaderst,vleaderlv from cus_fielddata
where scope='HrmCustomFieldByInfoType' and scopeid=3 and id=:new.dept_principal;
select sum(nvl(staff_num,0)) into vplan from JCL_ORG_STAFF
where plan_id in (select id from JCL_ORG_STAFFPLAN where time_start<=vdatebegin and time_end>=vdatebegin) and dept_id=:new.id;
select count(1) into vonjob from hrmresource where status<=3 and departmentid=vecid;
delete from jcl_org_map where ftype=2 and fobjid=:new.id and fdatebegin=vdatebegin;
update jcl_org_map set fdateend=vdatebegin-1 where ftype=2 and fobjid=:new.id and fdateend>vdatebegin;
if nvl(:new.forbidden_tag,0)=0 and nvl(:new.DELETE_TYPE,0)=0 then
insert into jcl_org_map
(id,ftype,fobjid,fecid,uuid,fclass,fclassname,fnumber,fname,fleader,fleaderimg,
fleadername,fleaderjobid,fleaderjob,fleaderlv,fleaderst,fparentid,fobjparentid,
fplan,fonjob,fisvitual,fdatebegin,fdateend)
values
(:new.id+st,2,:new.id,vecid,:new.uuid,0,'行政维度',:new.dept_no,:new.dept_name,:new.dept_principal,
vleaderimg,vleadername,veaderjobid,vleaderjob,vleaderlv,vleaderst,vparentid,vobjparentid,
vplan,vonjob,0,vdatebegin,to_date('2099-12-31','yyyy-mm-dd'));
end if;
end if;
end;
create or replace trigger JCL_ORG_job_ed after insert or update on JCL_ORG_job FOR EACH ROW
declare
st int;
sj int;
vplan int;
vonjob int;
vdatebegin date;
vparentid int;
vobjparentid int;
begin
if :new.job_name!=:old.job_name or :new.parent_dept!=:old.parent_dept or :new.parent_job!=:old.parent_job
or :new.forbidden_tag!=:old.forbidden_tag or :new.DELETE_TYPE!=:old.DELETE_TYPE then
st:=100000000;
sj:=200000000;
vdatebegin:=to_date(sysdate);
select case nvl(:new.parent_job,0) when 0 then :new.parent_dept+st else :new.parent_job+sj end,
case nvl(:new.parent_job,0) when 0 then :new.parent_dept else :new.parent_job end
into vparentid,vobjparentid from dual;
select sum(nvl(staff_num,0)) into vplan from JCL_ORG_STAFF
where plan_id in (select id from JCL_ORG_STAFFPLAN where time_start<=vdatebegin and time_end>=vdatebegin) and job_id=:new.id;
select count(1) into vonjob from hrmresource where status<=3
and departmentid=(select id from hrmdepartment where uuid=(select uuid from JCL_ORG_DEPT where id=:new.PARENT_DEPT))
and jobtitle in (select id from hrmjobtitles where JOBTITLENAME=:new.JOB_NAME);
delete from jcl_org_map where ftype=3 and fobjid=:new.id and fdatebegin=vdatebegin;
update jcl_org_map set fdateend=vdatebegin-1 where ftype=3 and fobjid=:new.id and fdateend>vdatebegin;
if nvl(:new.forbidden_tag,0)=0 and nvl(:new.DELETE_TYPE,0)=0 then
insert into jcl_org_map
(id,ftype,fobjid,fclass,fclassname,fnumber,fname,fparentid,fobjparentid,
fplan,fonjob,fisvitual,fdatebegin,fdateend)
values
(:new.id+sj,3,:new.id,0,'行政维度',:new.job_no,:new.job_name,vparentid,vobjparentid,
vplan,vonjob,0,vdatebegin,to_date('2099-12-31','yyyy-mm-dd'));
end if;
end if;
end;
create or replace trigger hrmresource_ed after insert or update on hrmresource FOR EACH ROW
declare
st int;
sj int;
sk int;
vdatebegin date;
vdelete int;
vleaderjob VARCHAR2(255);
vparentid int;
vobjparentid int;
vleaderst VARCHAR2(255);
vleaderlv VARCHAR2(255);
vstr VARCHAR2(255);
vwz int;
begin
if :new.lastname!=:old.lastname or :new.status!=:old.status then
st:=100000000;
sj:=200000000;
sk:=300000000;
vdatebegin:=to_date(sysdate);
if :new.status<=3 then
vdelete:=0;
else
vdelete:=1;
end if;
select jobtitlemark into vleaderjob from hrmjobtitles where id=:new.jobtitle;
select nvl(field100008,''),nvl(field100007,'') into vleaderst,vleaderlv from cus_fielddata
where scope='HrmCustomFieldByInfoType' and scopeid=3 and id=:new.id;
delete from jcl_org_map where ftype=4 and fobjid=:new.id and fdatebegin=vdatebegin;
update jcl_org_map set fdateend=vdatebegin-1 where ftype=4 and fobjid=:new.id and fdateend>vdatebegin;
select nvl(field100002,'') into vstr from cus_fielddata where scope='HrmCustomFieldByInfoType' and scopeid=3 and id=:new.id;
vwz:=Instr(vstr,'_');
vobjparentid:=to_number(substr(vstr,vwz+1,length(vstr)-vwz));
vparentid:=vobjparentid+sj;
if vdelete=0 then
insert into jcl_org_map
(id,ftype,fobjid,fecid,uuid,fclass,fclassname,fnumber,fname,fleaderimg,
fleadername,fleaderjobid,fleaderjob,fleaderlv,fleaderst,fparentid,fobjparentid,fisvitual,fdatebegin,fdateend)
values
(:new.id+sk,4,:new.id,:new.id,:new.uuid,0,'行政维度',:new.workcode,:new.lastname,:new.messagerurl,
:new.lastname,:new.jobtitle,vleaderjob,vleaderlv,vleaderst,vparentid,vobjparentid,0,vdatebegin,to_date('2099-12-31','yyyy-mm-dd'));
end if;
end if;
end;
create or replace trigger cus_fielddata_jclgw after insert or update on cus_fielddata FOR EACH ROW
declare
st int;
sj int;
sk int;
vnumber VARCHAR2(255);
vname VARCHAR2(255);
vleaderimg VARCHAR2(255);
vleadername VARCHAR2(255);
vleaderjobid VARCHAR2(255);
vuuid VARCHAR2(255);
vdatebegin date;
vdelete int;
vleaderjob VARCHAR2(255);
vparentid int;
vobjparentid int;
vleaderst VARCHAR2(255);
vleaderlv VARCHAR2(255);
vstr VARCHAR2(255);
vwz int;
begin
if :new.field100002!=:old.field100002 then
st:=100000000;
sj:=200000000;
sk:=300000000;
vdatebegin:=to_date(sysdate);
select workcode,lastname,case when status<=3 then 0 else 1 end,messagerurl,lastname,jobtitle,uuid
into vnumber,vname,vdelete,vleaderimg,vleadername,vleaderjobid,vuuid from hrmresource where id=:new.id;
select jobtitlemark into vleaderjob from hrmjobtitles where id=vleaderjobid;
select nvl(field100008,''),nvl(field100007,'') into vleaderst,vleaderlv from cus_fielddata
where scope='HrmCustomFieldByInfoType' and scopeid=3 and id=:new.id;
vstr:=nvl(:new.field100002,'');
vwz:=Instr(vstr,'_');
vobjparentid:=to_number(substr(vstr,vwz+1,length(vstr)-vwz));
vparentid:=vobjparentid+sj;
delete from jcl_org_map where ftype=4 and fobjid=:new.id and fdatebegin=vdatebegin;
update jcl_org_map set fdateend=vdatebegin-1 where ftype=4 and fobjid=:new.id and fdateend>vdatebegin;
if vdelete=0 then
insert into jcl_org_map
(id,ftype,fobjid,fecid,uuid,fclass,fclassname,fnumber,fname,fleaderimg,
fleadername,fleaderjobid,fleaderjob,fleaderlv,fleaderst,fparentid,fobjparentid,fisvitual,fdatebegin,fdateend)
values
(:new.id+sk,4,:new.id,:new.id,vuuid,0,'行政维度',vnumber,vname,vleaderimg,
vleadername,vleaderjobid,vleaderjob,vleaderlv,vleaderst,vparentid,vobjparentid,0,vdatebegin,to_date('2099-12-31','yyyy-mm-dd'));
end if;
end if;
end;
insert into jcl_org_map
(id,ftype,fobjid,fecid,uuid,fclass,fclassname,fnumber,fname,fleader,fleaderimg,
fleadername,fleaderjobid,fleaderjob,fleaderlv,fleaderst,fparentid,fobjparentid,
fplan,fonjob,fisvitual,fdatebegin,fdateend)
select 0,0,0,1,uuid,0,'行政维度','00',companyname,0,'','',0,'','','',-1,0,0,0,0,to_date(sysdate),to_date('2099-12-31','yyyy-mm-dd') from HrmCompany;
insert into jcl_org_map
(id,ftype,fobjid,fecid,uuid,fclass,fclassname,fnumber,fname,fleader,fleaderimg,
fleadername,fleaderjobid,fleaderjob,fleaderlv,fleaderst,fparentid,fobjparentid,
fplan,fonjob,fisvitual,fdatebegin,fdateend)
select a.id,1,a.id,b.id,a.uuid,0,'行政维度',a.comp_no,a.comp_name,a.comp_principal,c.messagerurl,
c.lastname,c.jobtitle,d.jobtitlemark,g.field100007,g.field100008,nvl(parent_company,0),nvl(parent_company,0),
nvl(e.fcnt,0),nvl(f.fcnt,0),0,to_date(sysdate),to_date('2099-12-31','yyyy-mm-dd')
from
JCL_ORG_comp a
left join HrmSubCompany b on a.uuid=b.uuid
left join hrmresource c on a.comp_principal=c.id
left join hrmjobtitles d on c.jobtitle=d.id
left join (select comp_id,sum(nvl(staff_num,0)) fcnt from JCL_ORG_STAFF
where plan_id in (select id from JCL_ORG_STAFFPLAN
where time_start<=to_date(sysdate) and time_end>to_date(sysdate))
group by comp_id) e on a.id=e.comp_id
left join (select subcompanyid1,count(1) fcnt from hrmresource where status<=3 group by subcompanyid1) f
on f.subcompanyid1=b.id
left join cus_fielddata g on c.id=g.id and g.scope='HrmCustomFieldByInfoType' and g.scopeid=3
where nvl(a.delete_type,0) <>1 and nvl(a.forbidden_tag,0) <>1;
insert into jcl_org_map
(id,ftype,fobjid,fecid,uuid,fclass,fclassname,fnumber,fname,fleader,fleaderimg,
fleadername,fleaderjobid,fleaderjob,fleaderlv,fleaderst,fparentid,fobjparentid,
fplan,fonjob,fisvitual,fdatebegin,fdateend)
select a.id+100000000,2,a.id,b.id,a.uuid,0,'行政维度',a.dept_no,a.dept_name,a.dept_principal,c.messagerurl,
c.lastname,c.jobtitle,d.jobtitlemark,g.field100007,g.field100008,
(case nvl(parent_dept,0) when 0 then parent_comp else parent_dept+100000000 end),
(case nvl(parent_dept,0) when 0 then parent_comp else parent_dept end),
nvl(e.fcnt,0),nvl(f.fcnt,0),0,to_date(sysdate),to_date('2099-12-31','yyyy-mm-dd')
from
JCL_ORG_dept a
left join HrmDepartment b on a.uuid=b.uuid
left join hrmresource c on a.dept_principal=c.id
left join hrmjobtitles d on c.jobtitle=d.id
left join (select dept_id,sum(nvl(staff_num,0)) fcnt from JCL_ORG_STAFF
where plan_id in (select id from JCL_ORG_STAFFPLAN
where time_start<=to_date(sysdate) and time_end>to_date(sysdate))
group by dept_id) e on a.id=e.dept_id
left join (select departmentid,count(1) fcnt from hrmresource where status<=3 group by departmentid) f on f.departmentid=b.id
left join cus_fielddata g on c.id=g.id and g.scope='HrmCustomFieldByInfoType' and g.scopeid=3
where nvl(a.delete_type,0) <>1 and nvl(a.forbidden_tag,0) <>1;
insert into jcl_org_map
(id,ftype,fobjid,fclass,fclassname,fnumber,fname,
fparentid,fobjparentid,
fplan,fonjob,fisvitual,fdatebegin,fdateend)
select a.id+200000000,3,a.id,0,'行政维度',a.job_no,a.job_name,
(case nvl(parent_job,0) when 0 then parent_dept+100000000 else parent_job+200000000 end),
(case nvl(parent_job,0) when 0 then parent_dept else parent_job end),
nvl(e.fcnt,0),nvl(f.fcnt,0),0,to_date(sysdate),to_date('2099-12-31','yyyy-mm-dd')
from JCL_ORG_job a
left join (select job_id,sum(nvl(staff_num,0)) fcnt from JCL_ORG_STAFF
where plan_id in (select id from JCL_ORG_STAFFPLAN
where time_start<=to_date(sysdate) and time_end>to_date(sysdate))
group by job_id) e on a.id=e.job_id
left join (select d.id,b.jobtitlename,count(1) fcnt
from hrmresource a
inner join HrmJobTitles b on a.jobtitle=b.id
inner join hrmdepartment c on a.departmentid=c.id
inner join jcl_org_dept d on a.uuid=b.uuid
group by d.id,b.jobtitlename) f
on f.id=a.parent_dept and a.job_name=f.jobtitlename
where nvl(a.delete_type,0) <>1 and nvl(a.forbidden_tag,0) <>1;
delete from cus_fielddata where scopeid=-1;
insert into cus_fielddata(scope, scopeid, id, field100002)
select 'HrmCustomFieldByInfoType',-1,a.id,'199_'||to_char(e.id)
from hrmresource a
left join HrmJobTitles b on a.jobtitle=b.id
left join hrmdepartment c on a.departmentid=c.id
left join JCL_ORG_DEPT d on c.uuid=d.uuid
left join jcl_org_job e on d.id=e.parent_dept and e.job_name=b.jobtitlename;
insert into jcl_org_map
(id,ftype,fobjid,fecid,uuid,fclass,fclassname,fnumber,fname,fleaderimg,
fleaderjobid,fleaderjob,fleaderlv,fleaderst,fparentid,fobjparentid,
fisvitual,fdatebegin,fdateend)
select a.id+300000000,4,a.id,a.id,a.uuid,0,'行政维度',a.workcode,a.lastname,a.messagerurl,a.jobtitle,
b.jobtitlemark,c.field100007,c.field100008,
to_number(substr(nvl(field100002,''),instr(nvl(field100002,''),'_')+1,length(nvl(field100002,''))-instr(nvl(field100002,''),'_')))+200000000,
to_number(substr(nvl(field100002,''),instr(nvl(field100002,''),'_')+1,length(nvl(field100002,''))-instr(nvl(field100002,''),'_'))),
0,to_date(sysdate),to_date('2099-12-31','yyyy-mm-dd')
from hrmresource a
left join hrmjobtitles b on a.jobtitle=b.id
left join cus_fielddata c on a.id=c.id and c.scope='HrmCustomFieldByInfoType' and c.scopeid=-1
where a.status<4