--alter table jcl_org_map drop column FLEADERIMG; --alter table jcl_org_map add FLEADERIMG varchar2(200); ----------初始化1: 当系统为老系统,客户已经存在数据,初始化时自动将数据写入到聚才林表中---------- --插数据 insert into JCL_ORG_COMP(comp_no,comp_name_short,comp_name,parent_company,forbidden_tag, show_order,uuid,creator,delete_type,create_time) select nvl(subcompanycode,''),subcompanyname,subcompanydesc,nvl(supsubcomid,0), nvl(canceled,0) ,nvl(showorder,0),uuid,1,0,SYSDATE from HrmSubCompany; --更新上级公司 update JCL_ORG_COMP t1 set t1.parent_company=(select c.id from HrmSubCompany a inner join HrmSubCompany b on a.supsubcomid=b.id inner join JCL_ORG_COMP c on b.uuid=c.uuid where a.uuid=t1.uuid); ---3、EC部门数据写入聚才林(HrmDepartment-->JCL_ORG_DEPT) --插入数据 insert into JCL_ORG_DEPT(dept_no, dept_name, dept_name_short,parent_comp, show_order,forbidden_tag,creator,delete_type,create_time,uuid) select a.departmentcode,a.departmentname,a.departmentmark,a.subcompanyid1,a.showorder,nvl(a.canceled,0),1,0,SYSDATE,uuid from HrmDepartment a left join HrmDepartmentDefined b on a.id=b.deptid; --跟新公司id update JCL_ORG_DEPT t1 set t1.parent_comp=(select c.id from HrmDepartment a inner join HrmSubCompany b on a.subcompanyid1=b.id inner join JCL_ORG_COMP c on b.uuid=c.uuid where t1.uuid=a.uuid); --更新上级部门id update JCL_ORG_dept t1 set t1.parent_dept=(select c.id from HrmDepartment a inner join HrmDepartment b on a.supdepid=b.id inner join JCL_ORG_dept c on b.uuid=c.uuid where t1.uuid=a.uuid); ---4、初始化岗位 insert into jcl_org_job(job_no, job_name, parent_comp, parent_dept, description, work_duty, work_authority, forbidden_tag, creator, delete_type, create_time, show_order) select b.jobtitlecode,b.jobtitlename,c.comid,d.deptid, cast(b.jobresponsibility as varchar(2000)),cast(b.jobresponsibility as varchar(2000)), cast(b.jobcompetency as varchar(2000)),nvl(b.canceled,0),1,0,SYSDATE,0 from (select distinct subcompanyid1,departmentid,jobtitle from HrmResource) a inner join HrmJobTitles b on a.jobtitle=b.id inner join (select a.id ecid,b.id comid from HrmSubCompany a inner join JCL_ORG_COMP b on a.uuid=b.uuid) c on a.subcompanyid1=c.ecid inner join (select a.id ecid,b.id deptid from HrmDepartment a inner join JCL_ORG_DEPT b on a.uuid=b.uuid) d on a.departmentid=d.ecid; --------------------------系统人员信息改造--------------------------------------------- --建视图 --职等职级 create or replace view v_jcl_zdzj as select id*-1 fid,sequence_name fname,0 fparentid,sequence_no fno from jcl_org_sequence where nvl(forbidden_tag,0)<>1 and nvl(delete_type,0)<>1 union select zj.id+1000,zj.grade_name,xl.id*-1,zj.grade_no from JCL_ORG_GRADE zj inner join jcl_org_sequence xl on zj.scheme_id=xl.scheme_id where nvl(zj.forbidden_tag,0)<>1 and nvl(zj.delete_type,0)<>1 union select zd.id,zd.level_name,zj.id+1000,zd.level_no from JCL_ORG_LEVEL zd inner join JCL_ORG_GRADE zj on ','+zj.level_id+',' like '%,'+cast(zd.id as varchar(10))+',%' where nvl(zd.forbidden_tag,0)<>1 and nvl(zd.delete_type,0)<>1; --岗位 INSERT INTO WF_BROWSER_CONFIG(TYPE,CLAZZ,DESCRIPTION,TITELEBEL) VALUES ('666','com.api.browser.service.impl.JobBrowserService','聚才林岗位管理',538781); INSERT INTO WORKFLOW_BROWSERURL(ID, LABELID, FIELDDBTYPE, BROWSERURL, TABLENAME, COLUMNAME, KEYCOLUMNAME, LINKURL, TYPEID, USEABLE, ORDERID) VALUES ( '666', '538781', 'varchar(4000)','/systeminfo/BrowserMain.jsp?url=','jcl_org_job', 'job_name', 'id', '/spa/organization/static/index.html#/main/organization/jobExtend/:id', '8', '1', '0' ); INSERT INTO WORKFLOW_BROWSERURL_MODULE(BROWSERID,MODULECODE)VALUES('666','workflow'); --职务 create or replace view v_jcl_post as select id*-1 fid,post_name fname,0 fparentid from JCL_ORG_POST where nvl(delete_type,0)<>1 union select id,post_info_name,post_id*-1 from JCL_ORG_POST_INFO where nvl(forbidden_tag,0)<>1 and nvl(delete_type,0)<>1; --newid函数 CREATE OR REPLACE FUNCTION newid RETURN VARCHAR2 IS guid VARCHAR2 (50); BEGIN guid := (RAWTOHEX(sys_guid())); RETURN substr(guid,1,8)||'-'||substr(guid,9,4)||'-'||substr(guid,13,4)||'-'||substr(guid,17,4)||'-'||substr(guid,21,12); END newid; --建模中,新建模块 declare orgid int; cubeuuid1 varchar2(100); appid1 int; modename varchar2(100); uuid varchar2(100); treeid int; t1 int; t2 int; t3 int; cnt int; lableid int; fieldname varchar2(100); fieldid1 int; field varchar2(100); sql1 varchar2(2000); begin select min(id) into orgid from hrmresource; cubeuuid1:=newid(); modename :='聚才林人事模块'; select count(*) into cnt from modetreefield where treeFieldName=modename; if cnt >0 then select id into appid1 from modetreefield where treeFieldName=modename; else insert into modetreefield(treeFieldName, superFieldid, allSuperFieldId, treelevel, showOrder, treeFieldDesc, isdelete, subcompanyid, icon, iconColor, iconBg,cubeuuid) values('聚才林人事模块',1,',0,1',1,-999,'聚才林专项应用(谨慎调整)',0,orgid, 'icon-cube-app-team','#fff','#4da0f8',cubeuuid1); select id into appid1 from modetreefield where cubeuuid=cubeuuid1; end if; --创建树 --职等职级 uuid :=lower(replace(newid(),'-','')); insert into mode_customtree(treename,creater, createdate, createtime, rootname, defaultaddress, showtype, isselsub, isonlyleaf, appid, treecode, isRefreshTree, isshowsearchtab, searchbrowserid, isQuickSearch, treeremark, combintree, combintreeway, defaulthideleft, showlevel, levelsplitchar, iscancellink,expandfirstnode) values('职等职级',1,'2022-07-01','00:00:00','职等职级','',1,0,1,appid1,uuid,0,0,0,0,'','',0,0,0,'/',0,1); select id,id into treeid,t1 from mode_customtree where treecode=uuid; insert into mode_customtreedetail(mainid, nodename, nodedesc, sourcefrom, sourceid, tablename, tablekey, tablesup, showfield, hreftype, hrefid, hreftarget, hrefrelatefield, nodeicon, supnode, supnodefield, nodefield, showorder, iconField, dataorder, datacondition, hrefField, rootids, isshowrootnode, isContainsSub) values(treeid,'职等职级','',2,0,'v_jcl_zdzj','fid','fparentid','fname',2,0,'#','','',0,'','',1,'','fno','','','',1,0); --职务 uuid :=lower(replace(newid(),'-','')); insert into mode_customtree(treename,creater, createdate, createtime, rootname, defaultaddress, showtype, isselsub, isonlyleaf, appid, treecode, isRefreshTree, isshowsearchtab, searchbrowserid, isQuickSearch, treeremark, combintree, combintreeway, defaulthideleft, showlevel, levelsplitchar, iscancellink,expandfirstnode) values('职务',1,'2022-07-01','00:00:00','职务','',1,0,1,appid1,uuid,0,0,0,0,'','',0,0,0,'/',0,1); select id,id into treeid,t3 from mode_customtree where treecode=uuid; insert into mode_customtreedetail(mainid, nodename, nodedesc, sourcefrom, sourceid, tablename, tablekey, tablesup, showfield, hreftype, hrefid, hreftarget, hrefrelatefield, nodeicon, supnode, supnodefield, nodefield, showorder, iconField, dataorder, datacondition, hrefField, rootids, isshowrootnode, isContainsSub) values(treeid,'职务','',2,0,'v_jcl_post','fid','fparentid','fname',2,0,'#','','',0,'','',1,'','','','','',1,0); --人员档案数据改造 --增加字段职等职级 fieldname:='职等职级'; fieldid1:=100001; field:='field'||to_char(fieldid1); select count(*) into cnt from HtmlLabelIndex where indexdesc=fieldname; if cnt>0 then select max(id) into lableid from HtmlLabelIndex where indexdesc=fieldname; else select min(indexid)-1 into lableid from HtmlLabelInfo; insert into HtmlLabelInfo(indexid, labelname, languageid) values(lableid,fieldname,7); insert into HtmlLabelInfo(indexid, labelname, languageid) values(lableid,fieldname,8); insert into HtmlLabelInfo(indexid, labelname, languageid) values(lableid,fieldname,9); insert into HtmlLabelIndex(id, indexdesc) values(lableid,fieldname); end if; insert into cus_formfield(scope, scopeid, fieldlable, fieldid, fieldorder, ismand, isuse, groupid, hrm_fieldlable, dmlUrl, ismodify) values('HrmCustomFieldByInfoType',-1,lableid,fieldid1,9,1,1,1,fieldname,t1,0); insert into cus_formdict(id, fielddbtype, fieldhtmltype, type, fieldname, fieldlabel, scope) values (fieldid1,'varchar(1000)',3,256,field,field,''); sql1 :='alter table cus_fielddata add '||field||' varchar(1000)'; execute immediate sql1; --增加字段担任岗位 fieldname:='担任岗位'; fieldid1:=100002; field:='field'||to_char(fieldid1); select count(*) into cnt from HtmlLabelIndex where indexdesc=fieldname; if cnt>0 then select max(id) into lableid from HtmlLabelIndex where indexdesc=fieldname; else select min(indexid)-1 into lableid from HtmlLabelInfo; insert into HtmlLabelInfo(indexid, labelname, languageid) values(lableid,fieldname,7); insert into HtmlLabelInfo(indexid, labelname, languageid) values(lableid,fieldname,8); insert into HtmlLabelInfo(indexid, labelname, languageid) values(lableid,fieldname,9); insert into HtmlLabelIndex(id, indexdesc) values(lableid,fieldname); end if; insert into cus_formfield(scope, scopeid, fieldlable, fieldid, fieldorder, ismand, isuse, groupid, hrm_fieldlable, dmlUrl, ismodify) values('HrmCustomFieldByInfoType',-1,lableid,fieldid1,8,1,1,1,fieldname,t2,0); insert into cus_formdict(id, fielddbtype, fieldhtmltype, type, fieldname, fieldlabel, scope) values (fieldid1,'varchar(1000)',3,666,field,field,''); sql1 :='alter table cus_fielddata add '||field||' varchar(1000)'; execute immediate sql1; --增加字段担任职务 fieldname:='担任职务'; fieldid1:=100003; field:='field'||to_char(fieldid1); select count(*) into cnt from HtmlLabelIndex where indexdesc=fieldname; if cnt>0 then select max(id) into lableid from HtmlLabelIndex where indexdesc=fieldname; else select min(indexid)-1 into lableid from HtmlLabelInfo; insert into HtmlLabelInfo(indexid, labelname, languageid) values(lableid,fieldname,7); insert into HtmlLabelInfo(indexid, labelname, languageid) values(lableid,fieldname,8); insert into HtmlLabelInfo(indexid, labelname, languageid) values(lableid,fieldname,9); insert into HtmlLabelIndex(id, indexdesc) values(lableid,fieldname); end if; insert into cus_formfield(scope, scopeid, fieldlable, fieldid, fieldorder, ismand, isuse, groupid, hrm_fieldlable, dmlUrl, ismodify) values('HrmCustomFieldByInfoType',-1,lableid,fieldid1,10,1,1,1,fieldname,t3,0); insert into cus_formdict(id, fielddbtype, fieldhtmltype, type, fieldname, fieldlabel, scope) values (fieldid1,'varchar(1000)',3,256,field,field,''); sql1 :='alter table cus_fielddata add '||field||' varchar(1000)'; execute immediate sql1; --增加字段职务序列名称 fieldname:='职务序列名称'; fieldid1:=100005; field:='field'||to_char(fieldid1); select count(*) into cnt from HtmlLabelIndex where indexdesc=fieldname; if cnt>0 then select max(id) into lableid from HtmlLabelIndex where indexdesc=fieldname; else select min(indexid)-1 into lableid from HtmlLabelInfo; insert into HtmlLabelInfo(indexid, labelname, languageid) values(lableid,fieldname,7); insert into HtmlLabelInfo(indexid, labelname, languageid) values(lableid,fieldname,8); insert into HtmlLabelInfo(indexid, labelname, languageid) values(lableid,fieldname,9); insert into HtmlLabelIndex(id, indexdesc) values(lableid,fieldname); end if; insert into cus_formfield(scope, scopeid, fieldlable, fieldid, fieldorder, ismand, isuse, groupid, hrm_fieldlable, dmlUrl, ismodify) values('HrmCustomFieldByInfoType',3,lableid,fieldid1,1,0,1,5,fieldname,'',0); insert into cus_formdict(id, fielddbtype, fieldhtmltype, type, fieldname, fieldlabel, scope) values (fieldid1,'varchar(200)',1,1,field,field,''); sql1 :='alter table cus_fielddata add '||field||' varchar(200)'; execute immediate sql1; --增加字段等级方案 fieldname:='等级方案'; fieldid1:=100006; field:='field'||to_char(fieldid1); select count(*) into cnt from HtmlLabelIndex where indexdesc=fieldname; if cnt>0 then select max(id) into lableid from HtmlLabelIndex where indexdesc=fieldname; else select min(indexid)-1 into lableid from HtmlLabelInfo; insert into HtmlLabelInfo(indexid, labelname, languageid) values(lableid,fieldname,7); insert into HtmlLabelInfo(indexid, labelname, languageid) values(lableid,fieldname,8); insert into HtmlLabelInfo(indexid, labelname, languageid) values(lableid,fieldname,9); insert into HtmlLabelIndex(id, indexdesc) values(lableid,fieldname); end if; insert into cus_formfield(scope, scopeid, fieldlable, fieldid, fieldorder, ismand, isuse, groupid, hrm_fieldlable, dmlUrl, ismodify) values('HrmCustomFieldByInfoType',3,lableid,fieldid1,1,0,1,5,fieldname,'',0); insert into cus_formdict(id, fielddbtype, fieldhtmltype, type, fieldname, fieldlabel, scope) values (fieldid1,'varchar(200)',1,1,field,field,''); sql1 :='alter table cus_fielddata add '||field||' varchar(200)'; execute immediate sql1; --增加字段职级 fieldname:='职级'; fieldid1:=100007; field:='field'||to_char(fieldid1); select count(*) into cnt from HtmlLabelIndex where indexdesc=fieldname; if cnt>0 then select max(id) into lableid from HtmlLabelIndex where indexdesc=fieldname; else select min(indexid)-1 into lableid from HtmlLabelInfo; insert into HtmlLabelInfo(indexid, labelname, languageid) values(lableid,fieldname,7); insert into HtmlLabelInfo(indexid, labelname, languageid) values(lableid,fieldname,8); insert into HtmlLabelInfo(indexid, labelname, languageid) values(lableid,fieldname,9); insert into HtmlLabelIndex(id, indexdesc) values(lableid,fieldname); end if; insert into cus_formfield(scope, scopeid, fieldlable, fieldid, fieldorder, ismand, isuse, groupid, hrm_fieldlable, dmlUrl, ismodify) values('HrmCustomFieldByInfoType',3,lableid,fieldid1,1,0,1,5,fieldname,'',0); insert into cus_formdict(id, fielddbtype, fieldhtmltype, type, fieldname, fieldlabel, scope) values (fieldid1,'varchar(200)',1,1,field,field,''); sql1 :='alter table cus_fielddata add '||field||' varchar(200)'; execute immediate sql1; --增加字段职等 fieldname:='职等'; fieldid1:=100008; field:='field'||to_char(fieldid1); select count(*) into cnt from HtmlLabelIndex where indexdesc=fieldname; if cnt>0 then select max(id) into lableid from HtmlLabelIndex where indexdesc=fieldname; else select min(indexid)-1 into lableid from HtmlLabelInfo; insert into HtmlLabelInfo(indexid, labelname, languageid) values(lableid,fieldname,7); insert into HtmlLabelInfo(indexid, labelname, languageid) values(lableid,fieldname,8); insert into HtmlLabelInfo(indexid, labelname, languageid) values(lableid,fieldname,9); insert into HtmlLabelIndex(id, indexdesc) values(lableid,fieldname); end if; insert into cus_formfield(scope, scopeid, fieldlable, fieldid, fieldorder, ismand, isuse, groupid, hrm_fieldlable, dmlUrl, ismodify) values('HrmCustomFieldByInfoType',3,lableid,fieldid1,1,0,1,5,fieldname,'',0); insert into cus_formdict(id, fielddbtype, fieldhtmltype, type, fieldname, fieldlabel, scope) values (fieldid1,'varchar(200)',1,1,field,field,''); sql1 :='alter table cus_fielddata add '||field||' varchar(200)'; execute immediate sql1; --增加字段职务分类 fieldname:='职务分类'; fieldid1:=100009; field:='field'||to_char(fieldid1); select count(*) into cnt from HtmlLabelIndex where indexdesc=fieldname; if cnt>0 then select max(id) into lableid from HtmlLabelIndex where indexdesc=fieldname; else select min(indexid)-1 into lableid from HtmlLabelInfo; insert into HtmlLabelInfo(indexid, labelname, languageid) values(lableid,fieldname,7); insert into HtmlLabelInfo(indexid, labelname, languageid) values(lableid,fieldname,8); insert into HtmlLabelInfo(indexid, labelname, languageid) values(lableid,fieldname,9); insert into HtmlLabelIndex(id, indexdesc) values(lableid,fieldname); end if; insert into cus_formfield(scope, scopeid, fieldlable, fieldid, fieldorder, ismand, isuse, groupid, hrm_fieldlable, dmlUrl, ismodify) values('HrmCustomFieldByInfoType',3,lableid,fieldid1,1,0,1,5,fieldname,'',0); insert into cus_formdict(id, fielddbtype, fieldhtmltype, type, fieldname, fieldlabel, scope) values (fieldid1,'varchar(200)',1,1,field,field,''); sql1 :='alter table cus_fielddata add '||field||' varchar(200)'; execute immediate sql1; --增加字段职务 fieldname:='职务'; fieldid1:=100010; field:='field'||to_char(fieldid1); select count(*) into cnt from HtmlLabelIndex where indexdesc=fieldname; if cnt>0 then select max(id) into lableid from HtmlLabelIndex where indexdesc=fieldname; else select min(indexid)-1 into lableid from HtmlLabelInfo; insert into HtmlLabelInfo(indexid, labelname, languageid) values(lableid,fieldname,7); insert into HtmlLabelInfo(indexid, labelname, languageid) values(lableid,fieldname,8); insert into HtmlLabelInfo(indexid, labelname, languageid) values(lableid,fieldname,9); insert into HtmlLabelIndex(id, indexdesc) values(lableid,fieldname); end if; insert into cus_formfield(scope, scopeid, fieldlable, fieldid, fieldorder, ismand, isuse, groupid, hrm_fieldlable, dmlUrl, ismodify) values('HrmCustomFieldByInfoType',3,lableid,fieldid1,1,0,1,5,fieldname,'',0); insert into cus_formdict(id, fielddbtype, fieldhtmltype, type, fieldname, fieldlabel, scope) values (fieldid1,'varchar(200)',1,1,field,field,''); sql1 :='alter table cus_fielddata add '||field||' varchar(200)'; execute immediate sql1; --增加字段职务 fieldname:='虚线上级'; fieldid1:=100004; field:='field'||to_char(fieldid1); select count(*) into cnt from HtmlLabelIndex where indexdesc=fieldname; if cnt>0 then select max(id) into lableid from HtmlLabelIndex where indexdesc=fieldname; else select min(indexid)-1 into lableid from HtmlLabelInfo; insert into HtmlLabelInfo(indexid, labelname, languageid) values(lableid,fieldname,7); insert into HtmlLabelInfo(indexid, labelname, languageid) values(lableid,fieldname,8); insert into HtmlLabelInfo(indexid, labelname, languageid) values(lableid,fieldname,9); insert into HtmlLabelIndex(id, indexdesc) values(lableid,fieldname); end if; insert into cus_formfield(scope, scopeid, fieldlable, fieldid, fieldorder, ismand, isuse, groupid, hrm_fieldlable, dmlUrl, ismodify) values('HrmCustomFieldByInfoType',-1,lableid,fieldid1,20,0,1,1,fieldname,'',0); insert into cus_formdict(id, fielddbtype, fieldhtmltype, type, fieldname, fieldlabel, scope) values (fieldid1,'text',3,17,field,field,''); sql1 :='alter table cus_fielddata add '||field||' varchar(200)'; execute immediate sql1; end; --人员其他字段改造 update hrm_formfield set isuse=1,ismand=1,allowhide=-1 where fieldname='sex'; --性别 update hrm_formfield set isuse=1,ismand=0,allowhide=-1 where fieldname='departmentid'; --部门 update hrm_formfield set isuse=1,ismand=0,allowhide=-1 where fieldname='jobtitle'; --岗位 update hrm_formfield set isuse=0,ismand=0,allowhide=-1 where fieldname='jobactivity'; --职务 update hrm_formfield set isuse=0,ismand=0,allowhide=-1 where fieldname='joblevel'; --职级 update hrm_formfield set isuse=0,ismand=0,allowhide=-1 where fieldname='jobcall'; --职称 update hrm_formfield set isuse=0,ismand=0,allowhide=-1 where fieldname='jobGroupId'; --职务类别 update hrm_formfield set isuse=0,ismand=0,allowhide=-1 where fieldname='jobactivitydesc';--职责描述 update hrm_formfield set isuse=1,ismand=0,allowhide=1,groupid=1,fieldorder=18 where fieldname='managerid';--直接上级 update hrm_formfield set isuse=1,ismand=0,allowhide=1,groupid=1,fieldorder=99 where fieldname='systemlanguage';--系统语言 update hrm_formfield set isuse=1,ismand=0,allowhide=1,groupid=1,fieldorder=21 where fieldname='assistantid';--助理 --------------------------组织架构图触发器--------------------------------------------- ------1、集团触发器 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; --2、公司触发器 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; --3、部门触发器 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; --4、岗位触发器 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; --5、人员触发器,写入组织架构图触发器 --新增、修改:姓名、状态 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; --fparentid,上级对象id,int,上级对象id(jcl)展示上级 --fobjparentid,父对象id,int,父对象id(jcl)业务上级 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));--截取岗位id,jcl 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 @fobjid=id,@id=id+@sk,@str=isnull(field100002,'') from inserted 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));--截取岗位id,jcl 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; ------------------------------ --初始化组织架构图 --0、集团 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; --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,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; --2、部门 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; --3、岗位 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; --4、人员 --初始化岗位 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