I'm trying to use merge into to insert only new records. I would like to collect the IDs for new records that got inserted and also the IDs for duplicate records that get ignored.
Here's the create statement for the table:
drop table SSZ_ME_MIS.test_update_table;
create table ssz_me_mis.test_update_table (
ID_col int not null generated always as identity, -- Primary Key
val_col_1 int not null,
val_col_2 varchar(255) not null,
constraint pk_test_update_table primary key (ID_col),
constraint uq_test_update_table unique (val_col_1, val_col_2)
);
and then, to populate some initial values:
insert into ssz_me_mis.test_update_table (val_col_1, val_col_2)
select *
from (values
(231, 'Value 1'),
(481, 'Value 2'),
(813, 'Value 3')
);
So, finally, I'd like to try to do this sort of insert:
select ID_col from final table (
merge into ssz_me_mis.test_update_table t using (
select *
from (values
(231, 'Value 1'),
(481, 'Value 2'),
(513, 'Value 4')
)
) as s (val_col_1, val_col_2)
on
t.val_col_1 = s.val_col_1
and t.val_col_2 = s.val_col_2
when not matched then
insert (val_col_1, val_col_2)
values (s.val_col_1, s.val_col_2)
else
ignore
);
Is there some way to accomplish this?
Something like this will run on Db2 LUW (assuming you are using ORGANIZE BY ROW
tables).
with s (val_col_1, val_col_2) AS (values
(231, 'Value 1'),
(481, 'Value 2'),
(513, 'Value 4')
)
, i as (select * from final table(
INSERT INTO ssz_me_mis.test_update_table ( val_col_1 , val_col_2)
select * from s where not exists (select 1 from ssz_me_mis.test_update_table t
where
t.val_col_1 = s.val_col_1
and t.val_col_2 = s.val_col_2
)
))
, u as (select count(*) as dummy from new table(
update ssz_me_mis.test_update_table t
set val_col_1 = (select val_col_1 from s where t.val_col_1 = s.val_col_1 and t.val_col_2 = s.val_col_2)
, val_col_2 = (select val_col_2 from s where t.val_col_1 = s.val_col_1 and t.val_col_2 = s.val_col_2)
where exists (select val_col_2 from s where t.val_col_1 = s.val_col_1 and t.val_col_2 = s.val_col_2)
))
select ID_col from i, u
I included a branch for updates, but logically you need some non-key columns for that to make sense. Your example is just an INSERT in practice, so I was a bit confused why you were using MERGE
at all.