利用dblink 做oracle到oracle的定时同步,以刚为卡中心做的一个同步为例 1、创建需要的dblink连接的数据库(若已经有,则不需要) 例: 查看 dblink : select * from dba_db_links; 创建 dblink : create database link ECARDRYXX connect to WPENG using '(DESCRIPTION = (ADDRESS_LIST = (ADDRESS = (PROTOCOL = TCP)(HOST = 202.120.85.118)(PORT = 1521)) ) (CONNECT_DATA = (SID = ORA92) ) )'; 2. 创建需要同步到对方数据的视图: 例: create or replace view ryxx as select ryjbxx.userid outid, xyzzjg.bmmc college, xszzjg.bmmc departname, ryjbxx.major, ryjbxx.typeof, ryjbxx.sfsf, ryjbxx.cn, ryjbxx.email, decode(sys_user.STATUS, '2', 'Yes', '4', 'No', 'No') inetUserStatus from ( select t1.xh userid, t1.xym , t1.xsm , t2.zymc major, 'student' typeof, t1.sfsf sfsf, t1.xm cn, t1.dzxx email from idc_u_xs.xs_xsjbxx t1, idc_u_jwmis.jw_zyxx t2 where t1.zyh = t2.zydh(+) -- 本科生 union all select t1.xh userid, t1.xym, t1.xsm, t2.zymc, 'student' typeof, '' sfsf, t1.xm cn, t1.email email from idc_u_yjs.yjs_yjsjbxx t1, idc_u_yjs.yjs_dict_bsxkzydm t2 where t1.zydm = t2.zydm(+) -- 研究生 union all select t1.zgh userid, '' xym, '' xsm, '' major, 'teacher' typeof, '' sfsf, t1.xm cn, t1.dzxx email from idc_u_rs.rs_zzryjbxx t1 -- 在职人员 union all select t1.zgh userid, '' xym, '' xsm, '' major, 'teacher' typeof, '' sfsf, t1.xm cn, t1.dzxx email from idc_u_rs.rs_xjrylsb t1 -- 新增人员 ) ryjbxx, idc_u_pub.sys_user, idc_u_rs.rs_zzjg xyzzjg, idc_u_rs.rs_zzjg xszzjg where ryjbxx.userid = sys_user.userid and ryjbxx.xym = xyzzjg.bmbh(+) -- 学院组织机构 and ryjbxx.xym = xszzjg.bmbh(+) -- 院系组织机构 3. 创建需要执行同步的pl/sql : 例如: 为了使用更模块化,更集中,建议同面向同一个库的pl/sql,写在同一个包下。 CREATE OR REPLACE PACKAGE ECARD IS PROCEDURE RYXXSYNC; END; CREATE OR REPLACE PACKAGE BODY ECARD IS PROCEDURE RYXXSYNC IS BEGIN delete from wpeng.ryxx@ecardryxx; --删除数据 insert into wpeng.ryxx@ecardryxx(outid, college, departname, major, typeof, sfsf, cn, email, inetuserstatus) select outid, college, departname, major, typeof, sfsf, cn, email, inetuserstatus from ryxx; --插入最新数据 END; END; 4. 创建job,定时执行同步: 例: 打开 sql命令窗口: variable ryxxsyncjob number; begin dbms_job.submit(:ryxxsyncjob, 'ECARD.RYXXSYNC;', SYSDATE, 'TRUNC(SYSDATE) + 1 + 2/24'); --每天凌晨两点执行。 commit; end;