create or replace
type glk_t_pllr_insert_values
as object(
values_correct varchar2(1)
, plpr_id number(27)
, pllr_logdoel varchar2(30)
, pllr_procesfase varchar2(30)
, pllr_run_startdate varchar2(14)
, pllr_thread_id varchar2(15)
, pllr_var_num_naam varchar2(31)
, pllr_var_num_waarde varchar2(200)
, pllr_var_char_naam varchar2(31)
, pllr_var_char_waarde varchar2(250)
, pllr_var_date_naam varchar2(31)
, pllr_var_date_waarde varchar2(14)
, pllr_verg_procesfase varchar2(30)
);
/
create or replace
type glk_t_pllr_aq_payload
as object(
plpr_procesnaam varchar2(50)
, plpr_versie varchar2(30)
, pllr_logdoel varchar2(30)
, pllr_procesfase varchar2(30)
, pllr_run_startdate varchar2(14)
, pllr_thread_id varchar2(15)
, pllr_var_num_naam varchar2(31)
, pllr_var_num_waarde varchar2(200)
, pllr_var_char_naam varchar2(31)
, pllr_var_char_waarde varchar2(250)
, pllr_var_date_naam varchar2(31)
, pllr_var_date_waarde varchar2(14)
, pllr_verg_procesfase varchar2(30)
);
/
begin
dbms_aqadm.create_queue_table(
queue_table => 'glk_owner.glk_t_pllr_qt'
, queue_payload_type => 'glk_owner.glk_t_pllr_aq_payload'
, multiple_consumers => false
);
dbms_aqadm.create_queue(
queue_name => 'glk_owner.glk_t_pllr_q'
, queue_table => 'glk_owner.glk_t_pllr_qt'
);
dbms_aqadm.start_queue(
queue_name => 'glk_owner.glk_t_pllr_q'
);
end;
/
create or replace package glk_t_pllr_aq
as
procedure enqueue_logregel(
p_procesnaam in varchar2
, p_versie in varchar2
, p_logdoel in varchar2
, p_procesfase in varchar2
, p_run_startdate in varchar2
, p_thread_id in varchar2
, p_var_num_naam in varchar2
, p_var_num_waarde in varchar2
, p_var_char_naam in varchar2
, p_var_char_waarde in varchar2
, p_var_date_naam in varchar2
, p_var_date_waarde in varchar2
, p_verg_procesfas in varchar2
);
procedure dequeue_logregel(
context raw
, reginfo sys.aq$_reg_info
, descr sys.aq$_descriptor
, payload raw
, payloadl number
);
end glk_t_pllr_aq;
create or replace package body glk_t_pllr_aq
as
procedure enqueue_logregel(
p_procesnaam in varchar2
, p_versie in varchar2
, p_logdoel in varchar2
, p_procesfase in varchar2
, p_run_startdate in varchar2
, p_thread_id in varchar2
, p_var_num_naam in varchar2
, p_var_num_waarde in varchar2
, p_var_char_naam in varchar2
, p_var_char_waarde in varchar2
, p_var_date_naam in varchar2
, p_var_date_waarde in varchar2
, p_verg_procesfas in varchar2
)
is
v_enqueue_options dbms_aq.enqueue_options_t;
v_message_properties dbms_aq.message_properties_t;
v_msgid raw(16);
v_payload glk_owner.glk_t_pllr_aq_payload;
begin
v_payload := glk_owner.glk_t_pllr_aq_payload(
plpr_procesnaam => p_procesnaam
, plpr_versie => p_versie
, pllr_logdoel => p_logdoel
, pllr_procesfase => p_procesfase
, pllr_run_startdate => p_run_startdate
, pllr_thread_id => p_thread_id
, pllr_var_num_naam => p_var_num_naam
, pllr_var_num_waarde => p_var_num_waarde
, pllr_var_char_naam => p_var_char_naam
, pllr_var_char_waarde => p_var_char_waarde
, pllr_var_date_naam => p_var_date_naam
, pllr_var_date_waarde => p_var_date_waarde
, pllr_verg_procesfase => p_verg_procesfas
);
dbms_aq.enqueue( queue_name => 'glk_owner.glk_t_pllr_q'
, enqueue_options => v_enqueue_options
, message_properties => v_message_properties
, payload => v_payload
, msgid => v_msgid
);
end enqueue_logregel;
procedure dequeue_logregel(
context raw
, reginfo sys.aq$_reg_info
, descr sys.aq$_descriptor
, payload raw
, payloadl number
)
is
v_rc_ok varchar2(1) := '0';
v_dequeue_options dbms_aq.dequeue_options_t;
v_message_properties dbms_aq.message_properties_t;
v_message_handle raw(16);
v_payload glk_owner.glk_t_pllr_aq_payload;
v_insert_values glk_owner.glk_t_pllr_insert_values;
v_plpr_id number(27);
begin
v_dequeue_options.msgid := descr.msg_id;
v_dequeue_options.wait := dbms_aq.no_wait;
dbms_aq.dequeue(
queue_name => descr.queue_name
, dequeue_options => v_dequeue_options
, message_properties => v_message_properties
, payload => v_payload
, msgid => v_message_handle
);
v_insert_values := glk_t_pllr_trg.checklogargs(
fp_plpr_procesnaam => v_payload.plpr_procesnaam
, fp_plpr_versie => v_payload.plpr_versie
, fp_pllr_logdoel => v_payload.pllr_logdoel
, fp_pllr_procesfase => v_payload.pllr_procesfase
, fp_pllr_run_startdate => v_payload.pllr_run_startdate
, fp_pllr_thread_id => v_payload.pllr_thread_id
, fp_pllr_var_num_naam => v_payload.pllr_var_num_naam
, fp_pllr_var_num_waarde => v_payload.pllr_var_num_waarde
, fp_pllr_var_char_naam => v_payload.pllr_var_char_naam
, fp_pllr_var_char_waarde => v_payload.pllr_var_char_waarde
, fp_pllr_var_date_naam => v_payload.pllr_var_date_naam
, fp_pllr_var_date_waarde => v_payload.pllr_var_date_waarde
, fp_pllr_verg_procesfase => v_payload.pllr_verg_procesfase
);
if v_insert_values.values_correct = v_rc_ok
then
v_plpr_id := v_insert_values.plpr_id;
else
select plpr_id
into v_plpr_id
from glk_t_plpr
where 1 = 1
and plpr_procesnaam = 'LogError'
and plpr_versie = '0'
;
end if;
glk_t_pllr_pg.insert_row(
p_plpr_id => v_plpr_id
, p_pllr_logdoel => v_insert_values.pllr_logdoel
, p_pllr_procesfase => v_insert_values.pllr_procesfase
, p_pllr_run_startdate => v_insert_values.pllr_run_startdate
, p_pllr_thread_id => v_insert_values.pllr_thread_id
, p_pllr_var_num_naam => v_insert_values.pllr_var_num_naam
, p_pllr_var_num_waarde => v_insert_values.pllr_var_num_waarde
, p_pllr_var_char_naam => v_insert_values.pllr_var_char_naam
, p_pllr_var_char_waarde => v_insert_values.pllr_var_char_waarde
, p_pllr_var_date_naam => v_insert_values.pllr_var_date_naam
, p_pllr_var_date_waarde => v_insert_values.pllr_var_date_waarde
, p_pllr_verg_procesfase => v_insert_values.pllr_verg_procesfase
);
commit;
end dequeue_logregel;
end glk_t_pllr_aq;
/
begin
dbms_aq.register(
reg_list => sys.aq$_reg_info_list(
sys.aq$_reg_info(
name => 'glk_owner.glk_t_pllr_q'
, namespace => dbms_aq.namespace_aq
, callback => 'plsql://glk_owner.glk_t_pllr_aq.dequeue_logregel'
, context => null
)
)
, reg_count => 1
);
end;
/