Oracle FAQ | Your Portal to the Oracle Knowledge Grid |
![]() |
![]() |
Home -> Community -> Mailing Lists -> Oracle-L -> Re: A Trigger question (LENGTHY!)
Yes. I was curious, so I did a little test:
Create 3 tables. Note the different datatypes.
SQL> create table dbm_1
2 (a varchar2(5) not null);
Table created.
SQL> create table dbm_2
2 (a number not null);
Table created.
SQL> create table dbm_3
2 (a varchar2(5) not null);
Table created.
Now create a trigger to populate dbm_2 with the values from dbm_1. Note that the trigger will fail if the datatypes mismatch:
SQL> create or replace trigger dbm_1_ariu
2 after insert or update
3 on dbm_1
4 for each row
5 begin
6 insert into dbm_2(a) values (:NEW.a);
7 end;
8 create trigger dbm_1_ariu
9 after insert or update
10 on dbm_1
11 for each row
12 begin
13 insert into dbm_2(a) values (:NEW.a);
14 exception
15 when others then
16 raise;
17 end;
18 /
Trigger created.
Test the trigger:
SQL> insert into dbm_1 values (1);
1 row created.
SQL> select count(*) from dbm_1;
COUNT(*)
1
SQL> select count(*) from dbm_2;
COUNT(*)
1
SQL> insert into dbm_1 values ('A');
insert into dbm_1 values ('A')
*
ERROR at line 1:
ORA-01722: invalid number ORA-06512: at "DBM.DBM_1_ARIU", line 5 ORA-04088: error during execution of trigger 'DBM.DBM_1_ARIU'
SQL> rollback;
Rollback complete.
Now, modify the trigger to insert values into dbm_3 if the insert fails.
SQL> create or replace trigger dbm_1_ariu
2 after insert or update
3 on dbm_1
4 for each row
5 begin
6 insert into dbm_2(a) values (:NEW.a);
7 exception
8 when others then
9 insert into dbm_3(a) values (:NEW.a);
10 end;
11
12 /
Trigger created.
SQL> insert into
2
SQL> insert into dbm_1(a) values (1);
1 row created.
SQL> select count(*) from dbm_1;
COUNT(*)
1
SQL> select count(*) from dbm_2;
COUNT(*)
1
SQL> select count(*) from dbm_3;
COUNT(*)
0
SQL> insert into dbm_1(a) values ('Brian');
1 row created.
SQL> select count(*) from dbm_1;
COUNT(*)
2
SQL> select count(*) from dbm_2;
COUNT(*)
1
SQL> select count(*) from dbm_3;
COUNT(*)
1
Notice that the trigger handled the exception perfectly. Of course, you'd want to code the exception more accurately, but I think this example proves that it is possible.
Brian
-- -------------------------------------- | Brian McGraw -- Oracle DBA | | Central Alabama Oracle Users Group | |------------------------------------| | mailto:BMcGraw_at_mindspring.com | | http://bmcgraw.home.mindspring.com | -------------------------------------- Andrey Bronfin wrote:Received on Wed Aug 22 2001 - 11:23:12 CDT
> Dear gurus !
> sorry for this RTFMable question , just don't have the docs in front of me
> here .
> Assume i have a trigger my_trig that performs an insert into tableB after an
> insert into tableA .
> The question is : what happens if the trigger gets broken (either disabled ,
> invalid or unable to do what it should do (for example if the tableB has
> reached maxextents) ) ?
> Does the user that inserts into tableA receive an ORA-**** error ?
> Is there a way to let the user insert into tableA , and capture the inserts
> into tableB that the trigger should perform , and do those inserts manually
> later ?
> Thanks a lot.
> Andrey.
> --
> Please see the official ORACLE-L FAQ: http://www.orafaq.com
> --
> Author: Andrey Bronfin
> INET: andreyb_at_elrontelesoft.com
>
> Fat City Network Services -- (858) 538-5051 FAX: (858) 538-5051
> San Diego, California -- Public Internet access / Mailing Lists
> --------------------------------------------------------------------
> To REMOVE yourself from this mailing list, send an E-Mail message
> to: ListGuru_at_fatcity.com (note EXACT spelling of 'ListGuru') and in
> the message BODY, include a line containing: UNSUB ORACLE-L
> (or the name of mailing list you want to be removed from). You may
> also send the HELP command for other information (like subscribing).
-- Please see the official ORACLE-L FAQ: http://www.orafaq.com -- Author: Brian McGraw INET: brian.mcgraw_at_infinity-insurance.com Fat City Network Services -- (858) 538-5051 FAX: (858) 538-5051 San Diego, California -- Public Internet access / Mailing Lists -------------------------------------------------------------------- To REMOVE yourself from this mailing list, send an E-Mail message to: ListGuru_at_fatcity.com (note EXACT spelling of 'ListGuru') and in the message BODY, include a line containing: UNSUB ORACLE-L (or the name of mailing list you want to be removed from). You may also send the HELP command for other information (like subscribing).
![]() |
![]() |