- Program -- 提供了scheduler 将要运行什么,包含program name,program type(PL/SQ块、存储过程、外部程序),program action(具体的程序实体,比如说一个PL/SQL块、或者是存储过程的名称、或者是外部程序的路径加名称) 。
- Schedules -- 指定何时何种频率来运行job,可以被不同的job重复的利用。比如说我有两个job都要求在每天的凌晨4点运行,那么两个job可以同时指定相同的schedule。
- Jobs -- 具体的作业的名称,依赖于那个program、schedule。也可以不指定program、schedule,而直接写入program、schedule的相应参数。
下面,分别使用DBMS_JOB和DBMS_SCHEDULER来创建job。
使用DBMS_JOB
1.创建测试表
点击(此处)折叠或打开
-
SQL> create table hoegh(h1 date);
-
-
Table created
-
- SQL>
点击(此处)折叠或打开
-
SQL>
-
SQL> create or replace procedure pro_hoegh is
-
2 begin
-
3 insert into hoegh values(sysdate);
-
4 COMMIT;
-
5 end pro_hoegh;
-
6 /
-
-
Procedure created
-
- SQL>
点击(此处)折叠或打开
-
SQL>
-
SQL> variable job1 number
-
SQL> begin
-
2 dbms_job.submit(:job1,\'pro_hoegh;\',sysdate,\'sysdate+1/1440\');--每天1440分钟,即一分钟运行test过程一次
-
3 end;
-
4 /
-
-
PL/SQL procedure successfully completed
-
job1
-
---------
-
1
-
- SQL>
点击(此处)折叠或打开
-
SQL>
-
SQL> begin
-
2 dbms_job.run(:job1);
-
3 end;
-
4 /
-
-
PL/SQL procedure successfully completed
-
job1
-
---------
-
1
-
- SQL>
点击(此处)折叠或打开
-
SQL> select to_char(h1,\'yyyy-mm-dd HH24:mi:ss\') H1 from hoegh;
-
-
H1
-
-------------------
-
2015-04-28 16:08:23
-
2015-04-28 16:07:21
-
- SQL>
5.停止job
点击(此处)折叠或打开
-
SQL>
-
SQL> begin
-
2 dbms_job.broken(1,true);
-
3 end;
-
4 /
-
-
PL/SQL procedure successfully completed
-
- SQL>
6.启用job
点击(此处)折叠或打开
-
SQL>
-
SQL> begin
-
2 dbms_job.broken(1,false);
-
3 end;
-
4 /
-
-
PL/SQL procedure successfully completed
-
- SQL>
点击(此处)折叠或打开
-
SQL>
-
SQL> begin
-
2 dbms_job.remove(1);
-
3 end;
-
4 /
-
-
PL/SQL procedure successfully completed
-
- SQL>
使用DBMS_SCHEDULER
1.创建测试表
点击(此处)折叠或打开
-
SQL> create table hoegh(h1 date);
-
-
Table created
-
- SQL>
点击(此处)折叠或打开
-
SQL>
-
SQL> create or replace procedure pro_hoegh is
-
2 begin
-
3 insert into hoegh values(sysdate);
-
4 COMMIT;
-
5 end pro_hoegh;
-
6 /
-
-
Procedure created
-
- SQL>
在schedule中定义了schedule名称、起止时间、调用间隔等参数。
点击(此处)折叠或打开
-
SQL>
-
SQL> begin
-
2 -- create_schedule
-
3 dbms_scheduler.create_schedule(schedule_name => \'schedule_hoegh\',
-
4 start_date => \'28-4月 -15 4.30.00.000 下午\',
-
5 repeat_interval => \'FREQ=MINUTELY; INTERVAL=1\',
-
6 end_date => \'29-4月 -15 4.30.00.000 下午\',
-
7 comments => \'TEST schedule\');
-
8 end;
-
9 /
-
-
PL/SQL procedure successfully completed
-
- SQL>
在program中定义了程序的类型、具体操作、参数个数等参数
点击(此处)折叠或打开
-
SQL>
-
SQL> begin
-
2 -- create_program
-
3 dbms_scheduler.create_program(program_name => \'program_hoegh\',
-
4 program_type => \'PLSQL_BLOCK\',
-
5 program_action => \'BEGIN PRO_HOEGH; END;\',
-
6 number_of_arguments => 0,
-
7 enabled => TRUE,
-
8 comments => \'TEST program\');
-
9 end;
-
10 /
-
-
PL/SQL procedure successfully completed
-
- SQL>
5.创建job
在job中指定了job_name,以及相关联的program_name、schedule_name等参数。
点击(此处)折叠或打开
-
SQL>
-
SQL> begin
-
2 -- create_job
-
3 dbms_scheduler.create_job(job_name => \'job_hoegh\',
-
4 program_name => \'program_hoegh\',
-
5 schedule_name => \'schedule_hoegh\',
-
6 job_class => \'DEFAULT_JOB_CLASS\',
-
7 enabled => true,
-
8 auto_drop => true,
-
9 comments => \'TEST procedure\');
-
10 end;
-
11 /
-
-
PL/SQL procedure successfully completed
-
- SQL>
点击(此处)折叠或打开
-
SQL>
-
SQL> begin
-
2 -- Call the procedure
-
3 dbms_scheduler.run_job(job_name => \'job_hoegh\',
-
4 use_current_session => false);
-
5 end;
-
6 /
-
-
PL/SQL procedure successfully completed
-
- SQL>
点击(此处)折叠或打开
-
SQL> select to_char(h1,\'yyyy-mm-dd HH24:mi:ss\') H1 from hoegh;
-
-
H1
-
-------------------
-
2015-04-28 16:30:00
-
2015-04-28 16:31:00
-
2015-04-28 16:32:00
-
2015-04-28 16:24:25
-
- SQL>
点击(此处)折叠或打开
-
SQL>
-
SQL> begin
-
2 dbms_scheduler.disable(\'job_hoegh\');
-
3 end;
-
4 /
-
-
PL/SQL procedure successfully completed
-
-
SQL>
-
SQL> select job_name,enabled,state from user_scheduler_jobs;
-
-
JOB_NAME ENABLED STATE
-
------------------------------ ------- ---------------
-
JOB_HOEGH FALSE DISABLED
-
- SQL>
点击(此处)折叠或打开
-
SQL>
-
SQL> begin
-
2 dbms_scheduler.enable(\'job_hoegh\');
-
3 end;
-
4 /
-
-
PL/SQL procedure successfully completed
-
-
SQL>
-
SQL> select job_name,enabled,state from user_scheduler_jobs;
-
-
JOB_NAME ENABLED STATE
-
------------------------------ ------- ---------------
-
JOB_HOEGH TRUE SCHEDULED
-
- SQL>
点击(此处)折叠或打开
-
SQL>
-
SQL> begin
-
2 dbms_scheduler.drop_job(\'job_hoegh\');
-
3 end;
-
4 /
-
-
PL/SQL procedure successfully completed
-
-
SQL>
-
SQL> select job_name,enabled,state from user_scheduler_jobs;
-
-
JOB_NAME ENABLED STATE
-
------------------------------ ------- ---------------
-
- SQL>