Details
-
Bug
-
Status: Closed
-
Major
-
Resolution: Fixed
-
10.2.2.1, 10.10.1.1
-
Normal
-
Release Note Needed, Repro attached
-
Deviation from standard
Description
Derby violates the SQL Standard when an UPDATE statement SETs an identity column to the value DEFAULT. Derby does the right thing for INSERTs, however.
For INSERTs, the 2011 Standard defines the meaning of DEFAULT in part 2, section 15.10 (Effect of inserting tables into base tables), general rule 2. For INSERTs, the DEFAULT value is the next value of the sequence generator which defines the identity column.
For UPDATEs, the 2011 Standard defines the meaning of DEFAULT in part 2, section 15.13 (Effect of replacing rows in base tables), general rule 5. For UPDATEs, the DEFAULT value is also the next value of the sequence generator which defines the identity column.
Note also that the 2011 Standard says that a GENERATED ALWAYS identity column can be SET to DEFAULT. Furthermore, that is the only explicit value accepted. See the 2011 Standard, part 2, section 14.15 (set clause list), syntax rule 5:
{
"If <set clause> SC specifies an <object column> that references a column of which some underlying column is either a generated column or an identity column whose descriptor indicates that values are always generated, then the <update source> specified in SC shall consist of a <default specification>."
}
What Derby actually does for UPDATEs is the following:
1) If the column was declared GENERATED ALWAYS, then Derby raises a compile-time error saying that the value of an identity column can't be overridden.
2) If the column was declared GENERATED BY DEFAULT, then Derby raises an execution time-error when trying to stuff a null into the column.
Correcting this bug would result in backwardly incompatible behavior. However, I think that the incompatibility is minor: it would mean the successful run of statements which previously raised errors.
I tripped across this problem while implementing the UPDATE action of the MERGE statement (DERBY-3155). If we decide to fix this bug, we will want to make sure that the UPDATE actions of MERGE statements also correctly handle DEFAULT values for identity columns.
The following script shows this problem:
connect 'jdbc:derby:memory:db;create=true';
create table t1( a int generated always as identity, b int );
create table t2( a int generated by default as identity, b int );
insert into t1( a, b ) values ( default, 100 );
insert into t2( a, b ) values ( default, 100 );
update t1 set a = default;
update t2 set a = default;
select * from t1;
select * from t2;
Attachments
Attachments
Issue Links
- is related to
-
DERBY-6429 Privilege checks for UPDATE statements are wrong.
- Closed
-
DERBY-6743 MERGE code needs changes since now UPDATE statement can change the identity column value using DEFAULT keyword.
- Open
-
DERBY-6742 For update statement, collect generated keys if Statement.RETURN_GENERATED_KEYS flag is supplied to the JDBC call.
- Resolved
-
DERBY-3888 ALTER TABLE ... ADD COLUMN cannot add identity columns
- Closed
-
DERBY-6753 Docs for IDENTITY_VAL_LOCAL needs to be updated to indicate that the return value will be impacted by single row UPDATE of identity column
- Closed
- relates to
-
DERBY-7037 NPEx at InternalTriggerExecutionContext.updateAICounters
- Open
-
DERBY-3155 Support for SQL:2003 MERGE statement
- Closed