-
-
Notifications
You must be signed in to change notification settings - Fork 258
Closed
Description
“WHEN NOT MATCHED BY SOURCE” was introduced with ticket #6681.
This has worked quite well so far.
However, I have now noticed that “WHEN NOT MATCHED BY SOURCE” behaves differently if the source is a stored procedure than if you specify derived-table as the source.
For “WHEN NOT MATCHED BY TARGET”, stored procedure and derived-table behave in the same way.
Here's an example, it may not make much sense, but you can see the difference in a nutshell.
Test-Table
CREATE GENERATOR TEST_ID_GEN;
CREATE TABLE TEST (
ID INTEGER NOT NULL,
TYP INTEGER,
CATEGORY INTEGER
);
ALTER TABLE TEST ADD CONSTRAINT PK_TEST PRIMARY KEY (ID);
SET TERM ^ ;
CREATE OR ALTER TRIGGER TEST_BI0 FOR TEST
ACTIVE BEFORE INSERT POSITION 0
AS
begin
/* Trigger text */
if (new.id is null) then
begin
new.id = gen_id( test_id_gen, 1);
end
end^
SET TERM ; ^
Test-Data
INSERT INTO TEST (ID, TYP, CATEGORY) VALUES (1, 1, 10);
INSERT INTO TEST (ID, TYP, CATEGORY) VALUES (2, 1, 10);
INSERT INTO TEST (ID, TYP, CATEGORY) VALUES (3, 1, 20);
INSERT INTO TEST (ID, TYP, CATEGORY) VALUES (4, 1, 20);
INSERT INTO TEST (ID, TYP, CATEGORY) VALUES (5, 1, 40);
INSERT INTO TEST (ID, TYP, CATEGORY) VALUES (6, 2, 10);
INSERT INTO TEST (ID, TYP, CATEGORY) VALUES (7, 2, 10);
INSERT INTO TEST (ID, TYP, CATEGORY) VALUES (8, 2, 10);
INSERT INTO TEST (ID, TYP, CATEGORY) VALUES (9, 2, 10);
INSERT INTO TEST (ID, TYP, CATEGORY) VALUES (10, 2, 10);
INSERT INTO TEST (ID, TYP, CATEGORY) VALUES (11, 2, 20);
INSERT INTO TEST (ID, TYP, CATEGORY) VALUES (12, 2, 20);
INSERT INTO TEST (ID, TYP, CATEGORY) VALUES (13, 2, 30);
INSERT INTO TEST (ID, TYP, CATEGORY) VALUES (14, 2, 60);
INSERT INTO TEST (ID, TYP, CATEGORY) VALUES (15, 2, 60);
INSERT INTO TEST (ID, TYP, CATEGORY) VALUES (16, 2, 60);
INSERT INTO TEST (ID, TYP, CATEGORY) VALUES (17, 2, 30);
INSERT INTO TEST (ID, TYP, CATEGORY) VALUES (18, 2, 30);
INSERT INTO TEST (ID, TYP, CATEGORY) VALUES (19, 2, 30);
INSERT INTO TEST (ID, TYP, CATEGORY) VALUES (20, 2, 30);
Test-Statement
execute block (
X_SOURCE_TYP type of column TEST.TYP = :SOURCE_TYP,
X_TARGET_TYP type of column TEST.TYP = :TARGET_TYP)
as
declare procedure SOURCEDATA
returns (
ID type of column TEST.ID,
TYP type of column TEST.TYP,
CATEGORY type of column TEST.CATEGORY)
as
begin
for select T.ID,
T.TYP,
T.CATEGORY
from TEST T
where T.TYP = :X_SOURCE_TYP
into :ID,
:TYP,
:CATEGORY
do
begin
suspend;
end
end
declare variable WITHSTOREDPROCEDURE boolean;
begin
-- :WITHSTOREDPROCEDURE = true; -- "when not matched by source" does not work
:WITHSTOREDPROCEDURE = false; -- works as expected
if ( :WITHSTOREDPROCEDURE) then
begin
-- "when not matched by source" does not work
merge into TEST T
using SOURCEDATA S
on T.TYP = :X_TARGET_TYP and
T.CATEGORY = S.CATEGORY
when not matched by target then
insert ( TYP,
CATEGORY)
values ( :X_TARGET_TYP,
S.CATEGORY);
merge into TEST T
using SOURCEDATA S
on T.CATEGORY = S.CATEGORY
when not matched by source and T.TYP = :X_TARGET_TYP then delete;
end
else
begin
-- works as expected
merge into TEST T
using ( select T.ID,
T.TYP,
T.CATEGORY
from TEST T
where T.TYP = :X_SOURCE_TYP) S
on T.TYP = :X_TARGET_TYP and
T.CATEGORY = S.CATEGORY
when not matched by target then
insert ( TYP,
CATEGORY)
values ( :X_TARGET_TYP,
S.CATEGORY);
merge into TEST T
using ( select T.ID,
T.TYP,
T.CATEGORY
from TEST T
where T.TYP = :X_SOURCE_TYP) S
on T.CATEGORY = S.CATEGORY
when not matched by source and T.TYP = :X_TARGET_TYP then delete;
end
end