mirror of
https://github.com/FirebirdSQL/firebird-qa.git
synced 2025-01-22 13:33:07 +01:00
223 lines
8.1 KiB
SQL
223 lines
8.1 KiB
SQL
-- Common DDL script for testst which veriry STATEMENT RESTART functionality that is able in READ CONSISTENSY.
|
|
-- About statement restart:
|
|
-- https://asktom.oracle.com/pls/asktom/f?p=100:11:::::P11_QUESTION_ID:11504247549852
|
|
SET BAIL ON;
|
|
--set echo on;
|
|
set autoddl off;
|
|
commit;
|
|
SET KEEP_TRAN_PARAMS ON;
|
|
set transaction no wait;
|
|
set term ^;
|
|
execute block as
|
|
begin
|
|
begin
|
|
execute statement 'drop trigger trg_commit';
|
|
when any do begin end
|
|
end
|
|
begin
|
|
execute statement 'drop trigger trg_rollback';
|
|
when any do begin end
|
|
end
|
|
end
|
|
^
|
|
commit
|
|
^
|
|
recreate view v_worker_log as select 1 x from rdb$database
|
|
^
|
|
recreate view v_test as select 1 x from rdb$database
|
|
^
|
|
recreate table tlog_want(id int)
|
|
^
|
|
recreate table tlog_done(id int)
|
|
^
|
|
recreate table test(id int)
|
|
^
|
|
execute block as
|
|
begin
|
|
begin
|
|
execute statement 'drop collation text_ci';
|
|
when any do begin end
|
|
end
|
|
end
|
|
^
|
|
set term ;^
|
|
commit;
|
|
|
|
recreate table test(id smallint generated by default as identity primary key using index test_pk_asc, att smallint default current_connection, x smallint);
|
|
recreate table tsrc(id smallint generated by default as identity primary key using index tsrc_pk_asc, att smallint default current_connection, x smallint);
|
|
recreate table flag(id smallint primary key);
|
|
recreate view v_test as select * from test;
|
|
commit;
|
|
create descending index test_id_des on test(id);
|
|
commit;
|
|
|
|
create collation text_ci for utf8 from unicode case insensitive;
|
|
commit;
|
|
|
|
|
|
recreate table tlog_want(
|
|
id smallint generated by default as identity
|
|
,att smallint default current_connection
|
|
,trn smallint default current_transaction
|
|
,who varchar(30) character set utf8 collate text_ci
|
|
,old_id smallint, old_x smallint
|
|
,new_id smallint, new_x smallint
|
|
,op varchar(3) character set utf8 collate text_ci
|
|
,rec_vers smallint
|
|
,global_cn smallint
|
|
,snap_no smallint
|
|
,dts timestamp default 'now'
|
|
);
|
|
recreate table tlog_done(
|
|
id smallint generated by default as identity
|
|
,att smallint default current_connection
|
|
,trn smallint default current_transaction
|
|
,who varchar(30) character set utf8 collate text_ci
|
|
,old_id smallint, old_x smallint
|
|
,new_id smallint, new_x smallint
|
|
,op varchar(3) character set utf8 collate text_ci
|
|
,rec_vers smallint
|
|
,global_cn smallint
|
|
,snap_no smallint
|
|
,dts timestamp default 'now'
|
|
);
|
|
|
|
recreate view v_worker_log as
|
|
select
|
|
d.old_id
|
|
,d.new_id
|
|
,d.op
|
|
,dense_rank()over(order by d.rec_vers) as rec_vers_rank
|
|
,dense_rank()over(order by d.snap_no) as snap_no_rank
|
|
,d.rec_vers as rec_vers_value -- leave for debug only
|
|
,d.snap_no as snap_no_value -- leave for debug only
|
|
,dts -- leave for debug only
|
|
from (
|
|
select
|
|
d.id
|
|
,d.old_id
|
|
,d.new_id
|
|
,d.op
|
|
,d.rec_vers
|
|
,d.snap_no
|
|
,d.dts
|
|
from tlog_done d
|
|
where d.who starting with 'worker' and d.op in ( 'ins', 'upd', 'del' )
|
|
) d
|
|
order by d.id
|
|
;
|
|
commit;
|
|
|
|
-----------------------------------------
|
|
|
|
set term ^;
|
|
recreate trigger test_biud for test inactive before insert or update or delete as
|
|
declare v_trn type of column tlog_want.trn;
|
|
declare v_rec_vers type of column tlog_want.rec_vers;
|
|
declare v_snap_no type of column tlog_want.snap_no;
|
|
declare v_global_cn type of column tlog_want.global_cn;
|
|
declare v_who type of column tlog_want.who;
|
|
begin
|
|
v_who = rdb$get_context('USER_SESSION', 'WHO');
|
|
v_trn = current_transaction;
|
|
|
|
--- does not work! always has value = 0 : v_rec_vers = iif(inserting or updating, new.rdb$record_version, old.rdb$record_version);
|
|
if (deleting) then
|
|
rdb$set_context('USER_TRANSACTION', 'REC_VERS', (select rdb$record_version from test t where t.id = :old.id) );
|
|
|
|
|
|
v_global_cn = rdb$get_context('SYSTEM', 'GLOBAL_CN');
|
|
v_snap_no = rdb$get_context('SYSTEM', 'SNAPSHOT_NUMBER');
|
|
|
|
in autonomous transaction do
|
|
begin
|
|
-- All following statements lead to firing trigger TRG_COMMIT which, in turn also adds rows to tlog* tables.
|
|
-- But we want to log only those commits which we explicitly entered.
|
|
-- In order to skip such excessive inserts, we temporary make assign NULL to the context variable 'WHO'.
|
|
-- Trigger TRG_COMMIT will do inserts only when this variable is not null.
|
|
rdb$set_context('USER_SESSION', 'WHO', null);
|
|
if (deleting) then
|
|
insert into tlog_want( trn, old_id, old_x, op, rec_vers, global_cn, snap_no, who ) values( :v_trn, :old.id, :old.x, 'DEL', :v_rec_vers, :v_global_cn, :v_snap_no, :v_who );
|
|
else if (updating) then
|
|
insert into tlog_want( trn, old_id, old_x, new_id, new_x, op, rec_vers, global_cn, snap_no, who ) values( :v_trn, :old.id, :old.x, :new.id, :new.x, 'UPD', :v_rec_vers, :v_global_cn, :v_snap_no, :v_who );
|
|
else
|
|
insert into tlog_want( trn, new_id, new_x, op, rec_vers, global_cn, snap_no, who ) values( :v_trn, :new.id, :new.x,'INS', :v_rec_vers, :v_global_cn, :v_snap_no, :v_who );
|
|
end
|
|
|
|
rdb$set_context('USER_SESSION', 'WHO', v_who );
|
|
|
|
|
|
end
|
|
^
|
|
recreate trigger test_aiud for test inactive after insert or update or delete as
|
|
declare v_trn type of column tlog_done.trn;
|
|
declare v_rec_vers type of column tlog_done.rec_vers;
|
|
declare v_snap_no type of column tlog_done.snap_no;
|
|
declare v_global_cn type of column tlog_done.global_cn;
|
|
declare v_who type of column tlog_done.who;
|
|
begin
|
|
v_who = rdb$get_context('USER_SESSION', 'WHO');
|
|
v_trn = current_transaction;
|
|
|
|
--- does not work! always has value = 0 : v_rec_vers = iif(inserting or updating, new.rdb$record_version, old.rdb$record_version);
|
|
if (not deleting) then
|
|
rdb$set_context('USER_TRANSACTION', 'REC_VERS', (select rdb$record_version from test t where t.id = :new.id) );
|
|
|
|
v_rec_vers = rdb$get_context('USER_TRANSACTION', 'REC_VERS');
|
|
|
|
v_global_cn = rdb$get_context('SYSTEM', 'GLOBAL_CN');
|
|
v_snap_no = rdb$get_context('SYSTEM', 'SNAPSHOT_NUMBER');
|
|
|
|
in autonomous transaction do
|
|
begin
|
|
-- All following statements lead to firing trigger TRG_COMMIT which, in turn also adds rows to tlog* tables.
|
|
-- But we done to log only those commits which we explicitly entered.
|
|
-- In order to skip such excessive inserts, we temporary make assign NULL to the context variable 'WHO'.
|
|
-- Trigger TRG_COMMIT will do inserts only when this variable is not null.
|
|
rdb$set_context('USER_SESSION', 'WHO', null);
|
|
if (deleting) then
|
|
insert into tlog_done( trn, old_id, old_x, op, rec_vers, global_cn, snap_no, who ) values( :v_trn, :old.id, :old.x, 'DEL', :v_rec_vers, :v_global_cn, :v_snap_no, :v_who );
|
|
else if (updating) then
|
|
insert into tlog_done( trn, old_id, old_x, new_id, new_x, op, rec_vers, global_cn, snap_no, who ) values( :v_trn, :old.id, :old.x, :new.id, :new.x, 'UPD', :v_rec_vers, :v_global_cn, :v_snap_no, :v_who );
|
|
else
|
|
insert into tlog_done( trn, new_id, new_x, op, rec_vers, global_cn, snap_no, who ) values( :v_trn, :new.id, :new.x,'INS', :v_rec_vers, :v_global_cn, :v_snap_no, :v_who );
|
|
end
|
|
|
|
rdb$set_context('USER_SESSION', 'WHO', v_who );
|
|
|
|
end
|
|
^
|
|
|
|
recreate trigger trg_commit inactive on transaction commit position 999 as
|
|
begin
|
|
if ( rdb$get_context('USER_SESSION', 'WHO') is NOT null ) then
|
|
begin
|
|
insert into tlog_want( op, who ) values( 'COM', rdb$get_context('USER_SESSION', 'WHO') );
|
|
insert into tlog_done( op, who ) values( 'COM', rdb$get_context('USER_SESSION', 'WHO') );
|
|
end
|
|
end
|
|
^
|
|
|
|
recreate trigger trg_rollback inactive on transaction rollback position 999 as
|
|
begin
|
|
if ( rdb$get_context('USER_SESSION', 'WHO') is NOT null ) then
|
|
in autonomous transaction do
|
|
begin
|
|
insert into tlog_want( op, who ) values( 'RBK', rdb$get_context('USER_SESSION', 'WHO') );
|
|
insert into tlog_done( op, who ) values( 'RBK', rdb$get_context('USER_SESSION', 'WHO') );
|
|
end
|
|
end
|
|
^
|
|
|
|
|
|
set term ;^
|
|
commit;
|
|
|
|
-- /*
|
|
alter trigger test_biud active;
|
|
alter trigger test_aiud active;
|
|
alter trigger trg_commit active;
|
|
alter trigger trg_rollback active;
|
|
commit;
|
|
-- */
|