|
1. 基于时间的schedule:
-
-
- BEGIN
- sys.dbms_scheduler.create_schedule(
- repeat_interval => 'FREQ=SECONDLY;INTERVAL=30',
- start_date => systimestamp at time zone 'Asia/Shanghai',
- end_date => to_timestamp_tz('2018-07-28 16:35:00 Asia/Shanghai', 'YYYY-MM-DD HH24:MI:SS TZR'),
- comments => 'schedule1',
- schedule_name => '"HR"."SCHEDULE1"');
- END;
复制代码 2. 基于时间的外部作业
(如果在windows上做:1. 打开组策略,用gpedit.msc命令。
2. 逐步找到compute configuration -- windows setting -- security setting -- local policy
-- user rights assignment -- log on as a batch job
3.双击"log on as a batch job",在这里加入你需要的操作系统user
4.再次在OEM的Host Credentials输入那些user和password,一切ok。)
- grant create job to hr;
- grant create external job to hr;
复制代码- begin
- dbms_scheduler.create_credential(credential_name => 'credential1',
- username => 'oracle',
- password => 'oracle');
- end;
-
复制代码 | OWNER | CREDENTIAL_NAME | USERNAME | DATABASE_ROLE | WINDOWS_DOMAIN | COMMENTS | 1 | SYS | CREDENTIAL1 | oracle | | | |
- grant execute on credential1 to hr;
复制代码 写一个shell脚本:
- #!/bin/sh
- export ORACLE_HOME=/u01/app/oracle/product/12.1.0/dbhome_2
- export ORACLE_SID=orcl
- export ORACLE_BASE=/u01/app/oracle
- /u01/app/oracle/product/12.1.0/dbhome_2/bin/sqlplus /nolog >> /home/oracle/job2a.log <<EOF
- conn hr/oracle_4U
- alter session set nls_date_format='yyyy-mm-dd:hh24:mi:ss';
- select sysdate from dual;
- exit
- EOF
- date +%Y%m%d-%H%M%S >> /home/oracle/job2b.log
复制代码-
-
- BEGIN
- DBMS_SCHEDULER.CREATE_PROGRAM(
- program_name=>'"HR"."PROGRAM2"',
- program_action=>'/home/oracle/job2.sh',
- program_type=>'EXECUTABLE',
- number_of_arguments=>0,
- comments=>'program2',
- enabled=>TRUE);
- END;
复制代码
跟schedule1类似:
- BEGIN
- sys.dbms_scheduler.create_schedule(
- repeat_interval => 'FREQ=SECONDLY;INTERVAL=30',
- start_date => systimestamp at time zone 'Asia/Shanghai',
- end_date => to_timestamp_tz('2018-07-28 16:52:00 Asia/Shanghai', 'YYYY-MM-DD HH24:MI:SS TZR'),
- comments => 'schedule2',
- schedule_name => '"HR"."SCHEDULE2"');
- END;
复制代码
3. 基于日历的schedule:
- BEGIN
- /* Complex scheduling example 1: Public Holidays */
- DBMS_SCHEDULER.CREATE_SCHEDULE
- (schedule_name => 'HR.SCHEDULE3',
- repeat_interval =>'freq=YEARLY;bydate=0701,0801,1001'
- ,comments => 'Politics Days'
- );
- END;
复制代码- BEGIN
- /* Complex scheduling example 2: Working Days */
- DBMS_SCHEDULER.CREATE_SCHEDULE
- (schedule_name => 'HR.SCHEDULE31',
- repeat_interval =>'freq=YEARLY;byday=MON,TUE,WED,THU,FRI;'
- ,comments => 'Run on every working day'
- );
- END;
复制代码- 'FREQ=YEARLY;BYYEARDAY=1,32,-306'
- The following example creates a schedule consisting of the first working day of every month in 2008:
- 'freq=MONTHLY;byday=MON,TUE,WED,THU,FRI;bysetpos=1'
- 1st and 3rd Monday each month:
- 'freq=MONTHLY;byday=1MON,3MON'
- The following example creates a schedule consisting of the last day of each quarter:
- 'freq=YEARLY;bymonth=MAR,JUN,SEP,DEC;bymonthday=-1'
复制代码- declare
- v_1 timestamp;
- begin
- for i in 1..3
- loop
- DBMS_SCHEDULER.EVALUATE_CALENDAR_STRING (
- calendar_string=>'FREQ=yearly;bydate=0701,0801,1001;BYHOUR=14;
- BYMINUTE=10;BYSECOND=0;exclude=HR.SCHEDULE31' ,
- start_date => sysdate,
- return_date_after => v_1,
- next_run_date => v_1 );
- dbms_output.put_line(to_char(v_1,'YYYY-MM-DD:HH24:MI:SS'));
- end loop;
- end;
- begin
- dbms_scheduler.create_schedule(schedule_name => 'HR.SCHEDULE32',
- repeat_interval => 'FREQ=yearly;bydate=0701,0801,1001;BYHOUR=14;
- BYMINUTE=10;BYSECOND=0;exclude=HR.SCHEDULE31' );
- end;
-
复制代码 -----------------------
4. 为了做基于事件的schedule,需要先制造queue:
- select * from dba_queues q where q.QUEUE_TYPE='NORMAL_QUEUE' ;
- select * from dba_queues q where q.QUEUE_TYPE='EXCEPTION_QUEUE';
- select * from dba_queues q where q.QUEUE_TYPE not in ('NORMAL_QUEUE','EXCEPTION_QUEUE');
- CREATE OR REPLACE TYPE t_event_queue_payload AS OBJECT (
- event_name VARCHAR2(30)
- );
- grant execute on t_event_queue_payload to hr;
- BEGIN
- -- Create a queue table to hold the event queue.
- DBMS_AQADM.create_queue_table(
- queue_table => 'event_queue_tab',
- queue_payload_type => 't_event_queue_payload',
- multiple_consumers => TRUE,
- comment => 'Queue Table For Event Messages');
- -- Create the event queue.
- DBMS_AQADM.create_queue (
- queue_name => 'event_queue',
- queue_table => 'event_queue_tab');
- -- Start the event queue.
- DBMS_AQADM.start_queue (queue_name => 'event_queue');
- END;
- select * from dba_queues q where q.QUEUE_TYPE='NORMAL_QUEUE'
- and q.QUEUE_TABLE=upper('event_queue_tab');
- select * from dba_queues q where q.QUEUE_TYPE='EXCEPTION_QUEUE'
- and q.QUEUE_TABLE=upper('event_queue_tab');
复制代码- begin
- dbms_aqadm.grant_queue_privilege(privilege => 'ENQUEUE',queue_name => 'event_queue',grantee => 'HR');
- end;
-
- begin
- dbms_aqadm.grant_queue_privilege(privilege => 'DEQUEUE',queue_name => 'event_queue',grantee => 'HR');
- end;
复制代码- grant execute on dbms_aq to hr;
复制代码 hr准备一些表和序列号来测试:
- CREATE TABLE scheduler_test (
- id NUMBER(10) NOT NULL,
- created_date DATE NOT NULL,
- event_name varchar2(40),
- CONSTRAINT scheduler_test_pk PRIMARY KEY (id)
- );
- CREATE SEQUENCE scheduler_test_seq;
- select * from scheduler_test;
复制代码 做基于事件的schedule4:
-
-
- BEGIN
- sys.dbms_scheduler.create_event_schedule(
- event_condition => 'tab.user_data.event_name = ''give_me_a_prod''',
- queue_spec => '"SYS"."EVENT_QUEUE"',
- start_date => systimestamp at time zone 'Asia/Shanghai',
- comments => 'schedule4',
- schedule_name => '"HR"."SCHEDULE4"');
- END;
复制代码- create or replace procedure hr.procnew( p_1 sys.t_event_queue_payload )
- is
- BEGIN
- INSERT INTO hr.scheduler_test
- VALUES (scheduler_test_seq.NEXTVAL, SYSDATE, p_1.event_name );
- COMMIT;
- END;
- begin
- dbms_scheduler.create_program (
- program_name => 'hr.program4',
- program_action=> 'hr.procnew',
- program_type => 'STORED_PROCEDURE',
- number_of_arguments => 1,
- enabled => false) ;
- end;
- select * from dba_scheduler_programs;
复制代码 | PROGRAM_NAME | PROGRAM_TYPE | PROGRAM_ACTION | NUMBER_OF_ARGUMENTS | ENABLED | DETACHED | SCHEDULE_LIMIT | PRIORITY | WEIGHT | MAX_RUNS | MAX_FAILURES | MAX_RUN_DURATION | NLS_ENV | COMMENTS | 1 | PROGRAM1 | PLSQL_BLOCK | begin
insert into t05317_1 values (to_char( sysdate ,'YYYY-MM-DD') );
end; | 0 | TRUE | FALSE | | 3 | 1 | | | | NLS_LANGUAGE='AMERICAN' NLS_TERRITORY='AMERICA' NLS_CURRENCY='$' NLS_ISO_CURRENCY='AMERICA' NLS_NUMERIC_CHARACTERS='.,' NLS_CALENDAR='GREGORIAN' NLS_DATE_FORMAT='DD-MON-RR' NLS_DATE_LANGUAGE='AMERICAN' NLS_SORT='BINARY' NLS_TIME_FORMAT='HH.MI.SSXFF AM' NLS_TIMESTAMP_FORMAT='DD-MON-RR HH.MI.SSXFF AM' NLS_TIME_TZ_FORMAT='HH.MI.SSXFF AM TZR' NLS_TIMESTAMP_TZ_FORMAT='DD-MON-RR HH.MI.SSXFF AM TZR' NLS_DUAL_CURRENCY='$' NLS_COMP='BINARY' NLS_LENGTH_SEMANTICS='BYTE' NLS_NCHAR_CONV_EXCP='FALSE' | PROGRAM1 | 2 | PROGRAM2 | EXECUTABLE | /home/oracle/job2.sh | 0 | TRUE | FALSE | | 3 | 1 | | | | NLS_LANGUAGE='AMERICAN' NLS_TERRITORY='AMERICA' NLS_CURRENCY='$' NLS_ISO_CURRENCY='AMERICA' NLS_NUMERIC_CHARACTERS='.,' NLS_CALENDAR='GREGORIAN' NLS_DATE_FORMAT='DD-MON-RR' NLS_DATE_LANGUAGE='AMERICAN' NLS_SORT='BINARY' NLS_TIME_FORMAT='HH.MI.SSXFF AM' NLS_TIMESTAMP_FORMAT='DD-MON-RR HH.MI.SSXFF AM' NLS_TIME_TZ_FORMAT='HH.MI.SSXFF AM TZR' NLS_TIMESTAMP_TZ_FORMAT='DD-MON-RR HH.MI.SSXFF AM TZR' NLS_DUAL_CURRENCY='$' NLS_COMP='BINARY' NLS_LENGTH_SEMANTICS='BYTE' NLS_NCHAR_CONV_EXCP='FALSE' | program2 | 3 | PROGRAM4 | STORED_PROCEDURE | procnew | 1 | FALSE | FALSE | | 3 | 1 | | | | NLS_LANGUAGE='AMERICAN' NLS_TERRITORY='AMERICA' NLS_CURRENCY='$' NLS_ISO_CURRENCY='AMERICA' NLS_NUMERIC_CHARACTERS='.,' NLS_CALENDAR='GREGORIAN' NLS_DATE_FORMAT='DD-MON-RR' NLS_DATE_LANGUAGE='AMERICAN' NLS_SORT='BINARY' NLS_TIME_FORMAT='HH.MI.SSXFF AM' NLS_TIMESTAMP_FORMAT='DD-MON-RR HH.MI.SSXFF AM' NLS_TIME_TZ_FORMAT='HH.MI.SSXFF AM TZR' NLS_TIMESTAMP_TZ_FORMAT='DD-MON-RR HH.MI.SSXFF AM TZR' NLS_DUAL_CURRENCY='$' NLS_COMP='BINARY' NLS_LENGTH_SEMANTICS='BYTE' NLS_NCHAR_CONV_EXCP='FALSE' | |
- begin
- dbms_scheduler.define_metadata_argument (
- program_name => 'hr.program4',
- argument_position => 1 ,
- metadata_attribute => 'EVENT_MESSAGE') ;
- end;
- select * from dba_scheduler_program_args;
复制代码 | PROGRAM_NAME | ARGUMENT_NAME | ARGUMENT_POSITION | ARGUMENT_TYPE | METADATA_ATTRIBUTE | DEFAULT_VALUE | OUT_ARGUMENT | 1 | PROGRAM4 | | 1 | | EVENT_MESSAGE | <NO VALUE> | FALSE |
- begin
- dbms_scheduler.enable ('program4');
- end;
复制代码
job4基于事件,没有预期运行时间:
APPS打消息:
- DECLARE
- l_enqueue_options DBMS_AQ.enqueue_options_t;
- l_message_properties DBMS_AQ.message_properties_t;
- l_message_handle RAW(16);
- l_queue_msg sys.t_event_queue_payload;
- BEGIN
- l_queue_msg := sys.t_event_queue_payload('give_me_a_prod');
- DBMS_AQ.enqueue(queue_name => 'sys.event_queue',
- enqueue_options => l_enqueue_options,
- message_properties => l_message_properties,
- payload => l_queue_msg,
- msgid => l_message_handle);
- COMMIT;
- END;
复制代码- select * from scheduler_test;
复制代码 | ID | CREATED_DATE | EVENT_NAME | 1 | 1 | 7/28/2018 6:11:26 PM | give_me_a_prod |
如果乱传递消息:
作业状态电子邮件通知:
- BEGIN
- sys.dbms_scheduler.disable( '"HR"."JOB4"' );
- sys.dbms_scheduler.set_attribute( name => '"HR"."JOB4"', attribute => 'raise_events', value => dbms_scheduler.job_succeeded + dbms_scheduler.job_failed + dbms_scheduler.job_completed + dbms_scheduler.job_chain_stalled);
- sys.dbms_scheduler.enable( '"HR"."JOB4"' );
- END;
复制代码- select * from dba_scheduler_global_attribute;
复制代码 | ATTRIBUTE_NAME | VALUE | 1 | MAX_JOB_SLAVE_PROCESSES | | 2 | LOG_HISTORY | 30 | 3 | DEFAULT_TIMEZONE | PRC | 4 | EMAIL_SERVER | | 5 | EMAIL_SERVER_ENCRYPTION | NONE | 6 | EMAIL_SERVER_CREDENTIAL | | 7 | EMAIL_SENDER | | 8 | LAST_OBSERVED_EVENT | 720D479E75657B7AE0535A00A8C06CD6::94138::SCHED::0000 | 9 | EVENT_EXPIRY_TIME | | 10 | FILE_WATCHER_COUNT | 0 | 11 | CURRENT_OPEN_WINDOW | SATURDAY_WINDOW |
- begin
- DBMS_SCHEDULER.SET_SCHEDULER_ATTRIBUTE
- ('email_server','station90.example.com:25');
- end;
复制代码- [root@station90 ~]# service postfix start
- 启动 postfix: [确定]
- [root@station90 ~]# service dovecot start
- 正在启动 Dovecot Imap: [确定]
- [root@station90 ~]#
复制代码
main.cf
(27 KB, 下载次数: 374)
|
|