The following is an example of an INSERT ALL. The requirement is that rows that exists in table A be inserted into table B, but only if they exist in the MASTER table. If not, then insert an error message into the LOG_MSG table.
create table a (
col1 number
,col2 varchar2(3)
,col3 varchar2(3)
)
/
create table b (
col1 number
,col2 varchar2(3)
,col3 varchar2(3)
)
/
create table master (
col1 varchar2(3)
,col2 number
)
/
create table log_msg
(msg varchar2(100)
,t timestamp default current_timestamp)
/
insert into a (col1,col2,col3)
select 1 col1, 'AAA' col2, 'P01' col3 from dual union all
select 2, 'BBB', 'Q01' from dual union all
select 3, 'CCC', 'S05' from dual union all
select 4, 'DDD', 'A02' from dual union all
select 5, 'EEE', 'B01' from dual union all
select 6, 'FFF', 'B03' from dual
/
insert into b (col1,col2,col3)
select 1 col1, 'AAA' col2, 'P01' col3 from dual union all
select 2, 'BBB', 'Q01' from dual union all
select 3, 'CCC', 'S05' from dual union all
select 5, 'EEE', 'B01' from dual
/
insert into master (col1,col2)
select 'P01', 100 from dual union all
select 'P02', 400 from dual union all
select 'Q01', 900 from dual union all
select 'Q02', 100 from dual union all
select 'S01', 800 from dual union all
select 'S05', 500 from dual union all
select 'B01', 200 from dual union all
select 'B03', 900 from dual
/
insert all
when Master_ID is not null then
into b (col1, col2, col3) values (col1, col2, col3)
when Master_ID is null then
into log_msg (msg) values (col1 || ' ' || col2 || ' ' || col3 || ' does not exist on Master')
select m.col1 as Master_ID
,a.col1 as Col1
,a.col2 as Col2
,a.col3 as Col3
from (
select a.col1, a.col2, a.col3
from a
left outer join b on a.col2 = b.col2
and a.col3 = b.col3
where b.col1 is null
) a
left outer join master m on a.col3 = m.col1
/
SQL> select * from b;
COL1 COL COL
---------- --- ---
1 AAA P01
2 BBB Q01
3 CCC S05
5 EEE B01
6 FFF FFF
SQL> select * from log_msg;
MSG T
------------------------------- -------------------------
4 DDD A02 does not exist Master 28-SEP-11 11.22.09.221000
I use this blog as a dumping ground for various scripts as well as solutions to Maths problems.
Labels
- Alter (2)
- Analytic functions (2)
- AQ (2)
- AWR (4)
- Collections (2)
- Connect By (2)
- Constraints (7)
- Date/Time calculations (3)
- Dynamic SQL (4)
- Explain Plan (1)
- Formatting (3)
- Functions (1)
- Generating Functions (1)
- Indexes (7)
- Insert (3)
- JMS (3)
- Joins (4)
- LOB (3)
- locking (5)
- Partitions (3)
- Performance (10)
- Security (1)
- SQL Plus (3)
- Tabibitosan (1)
- Triggers (1)
- Views (1)
- XML (4)
Script categories
- Performance (10)
- Constraints (7)
- Indexes (7)
- locking (5)
- AWR (4)
- Dynamic SQL (4)
- Joins (4)
- XML (4)
- Date/Time calculations (3)
- Formatting (3)
- Insert (3)
- JMS (3)
- LOB (3)
- Partitions (3)
- SQL Plus (3)
- AQ (2)
- Analytic functions (2)
- Collections (2)
- Connect By (2)
- Explain Plan (1)
- Functions (1)
- Security (1)
- Triggers (1)
- Views (1)
No comments:
Post a Comment