The primary index of the target table cannot be an identity column if you specify an INSERT clause even when the ON and INSERT clauses are valid.
However, if the source relation is created from a single row subquery, or if you do not specify an INSERT clause, then the target table primary index can also be an identity column.
Consider the following rules and examples based on these table definitions:
CREATE TABLE t1 ( x1 INTEGER GENERATED ALWAYS AS IDENTITY, y1 INTEGER, z1 INTEGER) PRIMARY INDEX(x1); CREATE TABLE t2 ( x2 INTEGER, y2 INTEGER, z2 INTEGER) PRIMARY INDEX(x2) UNIQUE INDEX(y2);
The rules, explicitly stated, are as follows:
- If you do not specify a WHEN NOT MATCHED THEN INSERT clause, the MERGE request is valid because there is no attempt to insert a value into x1, which is both the primary index of t1 and an identity column.
For example, the following MERGE request is valid because no WHEN NOT MATCHED THEN INSERT clause is specified:
MERGE INTO t1 USING (SELECT x2, y2, z2 FROM t2 WHERE y2 = 1) ON x1 = x2 WHEN MATCHED THEN UPDATE SET y1 = y2;
- If you do specify a WHEN NOT MATCHED THEN INSERT clause, the MERGE request fails and returns an error to the requestor because an attempt is made to insert a value into x1, which is both the primary index of t1 and an identity column.
For example, the following MERGE request fails because it specifies a WHEN NOT MATCHED THEN INSERT clause that attempts to insert the value of x2 into x1, which is both the primary index of t1 and an identity column:
MERGE INTO t1 USING (SELECT x2, y2, z2 FROM t2 WHERE y2 = 1) ON x1 = x2 WHEN MATCHED THEN UPDATE SET y1 = y2 WHEN NOT MATCHED THEN INSERT (x2, y2, z2);