diff --git a/doc/src/sgml/ref/create_table.sgml b/doc/src/sgml/ref/create_table.sgml
index 9f8b59de50a..155866c7c83 100644
--- a/doc/src/sgml/ref/create_table.sgml
+++ b/doc/src/sgml/ref/create_table.sgml
@@ -842,15 +842,27 @@ WITH ( MODULUS numeric_literal, REM
The clauses ALWAYS and BY DEFAULT
- determine how the sequence value is given precedence over a
- user-specified value in an INSERT statement.
- If ALWAYS is specified, a user-specified value is
- only accepted if the INSERT statement
- specifies OVERRIDING SYSTEM VALUE. If BY
- DEFAULT is specified, then the user-specified value takes
- precedence. See for details. (In
- the COPY command, user-specified values are always
- used regardless of this setting.)
+ determine how explicitly user-specified values are handled in
+ INSERT and UPDATE commands.
+
+
+
+ In an INSERT command, if ALWAYS is
+ selected, a user-specified value is only accepted if the
+ INSERT statement specifies OVERRIDING SYSTEM
+ VALUE. If BY DEFAULT is selected, then the
+ user-specified value takes precedence. See
+ for details. (In the COPY command, user-specified
+ values are always used regardless of this setting.)
+
+
+
+ In an UPDATE command, if ALWAYS is
+ selected, any update of the column to any value other than
+ DEFAULT will be rejected. If BY
+ DEFAULT is selected, the column can be updated normally.
+ (There is no OVERRIDING clause for the
+ UPDATE command.)
diff --git a/doc/src/sgml/ref/insert.sgml b/doc/src/sgml/ref/insert.sgml
index e829c61642d..a6cec6b02ea 100644
--- a/doc/src/sgml/ref/insert.sgml
+++ b/doc/src/sgml/ref/insert.sgml
@@ -206,10 +206,19 @@ INSERT INTO table_name [ AS OVERRIDING SYSTEM VALUE
- Without this clause, it is an error to specify an explicit value
- (other than DEFAULT) for an identity column defined
- as GENERATED ALWAYS. This clause overrides that
- restriction.
+ If this clause is specified, then any values supplied for identity
+ columns will override the default sequence-generated values.
+
+
+
+ For an identity column defined as GENERATED ALWAYS,
+ it is an error to insert an explicit value (other than
+ DEFAULT) without specifying either
+ OVERRIDING SYSTEM VALUE or OVERRIDING USER
+ VALUE. (For an identity column defined as
+ GENERATED BY DEFAULT, OVERRIDING SYSTEM
+ VALUE is the normal behavior and specifying it does nothing,
+ but PostgreSQL allows it as an extension.)
@@ -219,8 +228,8 @@ INSERT INTO table_name [ AS
If this clause is specified, then any values supplied for identity
- columns defined as GENERATED BY DEFAULT are ignored
- and the default sequence-generated values are applied.
+ columns are ignored and the default sequence-generated values are
+ applied.
@@ -238,7 +247,8 @@ INSERT INTO table_name [ AS DEFAULT VALUES
- All columns will be filled with their default values.
+ All columns will be filled with their default values, as if
+ DEFAULT were explicitly specified for each column.
(An OVERRIDING clause is not permitted in this
form.)
@@ -258,8 +268,11 @@ INSERT INTO table_name [ AS DEFAULT
- The corresponding column will be filled with
- its default value.
+ The corresponding column will be filled with its default value. An
+ identity column will be filled with a new value generated by the
+ associated sequence. For a generated column, specifying this is
+ permitted but merely specifies the normal behavior of computing the
+ column from its generation expression.
diff --git a/doc/src/sgml/ref/update.sgml b/doc/src/sgml/ref/update.sgml
index f58dcd8877b..4840bf560c1 100644
--- a/doc/src/sgml/ref/update.sgml
+++ b/doc/src/sgml/ref/update.sgml
@@ -142,8 +142,11 @@ UPDATE [ ONLY ] table_name [ * ] [
DEFAULT
- Set the column to its default value (which will be NULL if no
- specific default expression has been assigned to it).
+ Set the column to its default value (which will be NULL if no specific
+ default expression has been assigned to it). An identity column will be
+ set to a new value generated by the associated sequence. For a
+ generated column, specifying this is permitted but merely specifies the
+ normal behavior of computing the column from its generation expression.
diff --git a/src/backend/rewrite/rewriteHandler.c b/src/backend/rewrite/rewriteHandler.c
index 3b4f28874aa..fe777c3103d 100644
--- a/src/backend/rewrite/rewriteHandler.c
+++ b/src/backend/rewrite/rewriteHandler.c
@@ -808,7 +808,9 @@ rewriteTargetListIU(List *targetList,
{
if (att_tup->attidentity == ATTRIBUTE_IDENTITY_ALWAYS && !apply_default)
{
- if (override != OVERRIDING_SYSTEM_VALUE)
+ if (override == OVERRIDING_USER_VALUE)
+ apply_default = true;
+ else if (override != OVERRIDING_SYSTEM_VALUE)
ereport(ERROR,
(errcode(ERRCODE_GENERATED_ALWAYS),
errmsg("cannot insert into column \"%s\"", NameStr(att_tup->attname)),
diff --git a/src/test/regress/expected/identity.out b/src/test/regress/expected/identity.out
index 7322b287650..7ac9df767f5 100644
--- a/src/test/regress/expected/identity.out
+++ b/src/test/regress/expected/identity.out
@@ -118,53 +118,72 @@ SELECT * FROM itest3;
(5 rows)
-- OVERRIDING tests
+-- GENERATED BY DEFAULT
+-- This inserts the row as presented:
INSERT INTO itest1 VALUES (10, 'xyz');
-INSERT INTO itest1 OVERRIDING USER VALUE VALUES (10, 'xyz');
+-- With GENERATED BY DEFAULT, OVERRIDING SYSTEM VALUE is not allowed
+-- by the standard, but we allow it as a no-op, since it is of use if
+-- there are multiple identity columns in a table, which is also an
+-- extension.
+INSERT INTO itest1 OVERRIDING SYSTEM VALUE VALUES (20, 'xyz');
+-- This ignores the 30 and uses the sequence value instead:
+INSERT INTO itest1 OVERRIDING USER VALUE VALUES (30, 'xyz');
SELECT * FROM itest1;
a | b
----+-----
1 |
2 |
10 | xyz
+ 20 | xyz
3 | xyz
-(4 rows)
+(5 rows)
+-- GENERATED ALWAYS
+-- This is an error:
INSERT INTO itest2 VALUES (10, 'xyz');
ERROR: cannot insert into column "a"
DETAIL: Column "a" is an identity column defined as GENERATED ALWAYS.
HINT: Use OVERRIDING SYSTEM VALUE to override.
-INSERT INTO itest2 OVERRIDING SYSTEM VALUE VALUES (10, 'xyz');
+-- This inserts the row as presented:
+INSERT INTO itest2 OVERRIDING SYSTEM VALUE VALUES (20, 'xyz');
+-- This ignores the 30 and uses the sequence value instead:
+INSERT INTO itest2 OVERRIDING USER VALUE VALUES (30, 'xyz');
SELECT * FROM itest2;
a | b
----+-----
1 |
2 |
- 10 | xyz
-(3 rows)
+ 20 | xyz
+ 3 | xyz
+(4 rows)
-- UPDATE tests
+-- GENERATED BY DEFAULT is not restricted.
UPDATE itest1 SET a = 101 WHERE a = 1;
UPDATE itest1 SET a = DEFAULT WHERE a = 2;
SELECT * FROM itest1;
a | b
-----+-----
10 | xyz
+ 20 | xyz
3 | xyz
101 |
4 |
-(4 rows)
+(5 rows)
-UPDATE itest2 SET a = 101 WHERE a = 1;
+-- GENERATED ALWAYS allows only DEFAULT.
+UPDATE itest2 SET a = 101 WHERE a = 1; -- error
ERROR: column "a" can only be updated to DEFAULT
DETAIL: Column "a" is an identity column defined as GENERATED ALWAYS.
-UPDATE itest2 SET a = DEFAULT WHERE a = 2;
+UPDATE itest2 SET a = DEFAULT WHERE a = 2; -- ok
SELECT * FROM itest2;
a | b
----+-----
1 |
- 10 | xyz
- 3 |
-(3 rows)
+ 20 | xyz
+ 3 | xyz
+ 4 |
+(4 rows)
-- COPY tests
CREATE TABLE itest9 (a int GENERATED ALWAYS AS IDENTITY, b text, c bigint);
diff --git a/src/test/regress/sql/identity.sql b/src/test/regress/sql/identity.sql
index b4cdd21bdd4..1bf2a976eb0 100644
--- a/src/test/regress/sql/identity.sql
+++ b/src/test/regress/sql/identity.sql
@@ -64,25 +64,42 @@ SELECT * FROM itest3;
-- OVERRIDING tests
+-- GENERATED BY DEFAULT
+
+-- This inserts the row as presented:
INSERT INTO itest1 VALUES (10, 'xyz');
-INSERT INTO itest1 OVERRIDING USER VALUE VALUES (10, 'xyz');
+-- With GENERATED BY DEFAULT, OVERRIDING SYSTEM VALUE is not allowed
+-- by the standard, but we allow it as a no-op, since it is of use if
+-- there are multiple identity columns in a table, which is also an
+-- extension.
+INSERT INTO itest1 OVERRIDING SYSTEM VALUE VALUES (20, 'xyz');
+-- This ignores the 30 and uses the sequence value instead:
+INSERT INTO itest1 OVERRIDING USER VALUE VALUES (30, 'xyz');
SELECT * FROM itest1;
+-- GENERATED ALWAYS
+
+-- This is an error:
INSERT INTO itest2 VALUES (10, 'xyz');
-INSERT INTO itest2 OVERRIDING SYSTEM VALUE VALUES (10, 'xyz');
+-- This inserts the row as presented:
+INSERT INTO itest2 OVERRIDING SYSTEM VALUE VALUES (20, 'xyz');
+-- This ignores the 30 and uses the sequence value instead:
+INSERT INTO itest2 OVERRIDING USER VALUE VALUES (30, 'xyz');
SELECT * FROM itest2;
-- UPDATE tests
+-- GENERATED BY DEFAULT is not restricted.
UPDATE itest1 SET a = 101 WHERE a = 1;
UPDATE itest1 SET a = DEFAULT WHERE a = 2;
SELECT * FROM itest1;
-UPDATE itest2 SET a = 101 WHERE a = 1;
-UPDATE itest2 SET a = DEFAULT WHERE a = 2;
+-- GENERATED ALWAYS allows only DEFAULT.
+UPDATE itest2 SET a = 101 WHERE a = 1; -- error
+UPDATE itest2 SET a = DEFAULT WHERE a = 2; -- ok
SELECT * FROM itest2;