We appear to have lost track of this. I have re-read everything and expanded your patch a bit with additional documentation and comments in the tests.

--
Peter Eisentraut              http://www.2ndQuadrant.com/
PostgreSQL Development, 24x7 Support, Remote DBA, Training & Services
From cb1faa444f4bbc0b26c9dd58feabe7c4b675114b Mon Sep 17 00:00:00 2001
From: Peter Eisentraut <pe...@eisentraut.org>
Date: Fri, 27 Mar 2020 12:12:14 +0100
Subject: [PATCH v2] Fix INSERT OVERRIDING USER VALUE behavior

The original implementation disallowed using OVERRIDING USER VALUE on
identity columns defined as GENERATED ALWAYS, which is not per
standard.  So allow that now.

Expand documentation and tests around this.

Author: Dean Rasheed <dean.a.rash...@gmail.com>
Discussion: 
https://www.postgresql.org/message-id/flat/CAEZATCVrh2ufCwmzzM%3Dk_OfuLhTTPBJCdFkimst2kry4oHepuQ%40mail.gmail.com
---
 doc/src/sgml/ref/create_table.sgml     | 30 +++++++++++++------
 doc/src/sgml/ref/insert.sgml           | 32 ++++++++++++++------
 doc/src/sgml/ref/update.sgml           |  7 +++--
 src/backend/rewrite/rewriteHandler.c   |  4 ++-
 src/test/regress/expected/identity.out | 41 +++++++++++++++++++-------
 src/test/regress/sql/identity.sql      | 25 +++++++++++++---
 6 files changed, 103 insertions(+), 36 deletions(-)

diff --git a/doc/src/sgml/ref/create_table.sgml 
b/doc/src/sgml/ref/create_table.sgml
index 15b50c56f0..547310b693 100644
--- a/doc/src/sgml/ref/create_table.sgml
+++ b/doc/src/sgml/ref/create_table.sgml
@@ -842,15 +842,27 @@ <title>Parameters</title>
 
      <para>
       The clauses <literal>ALWAYS</literal> and <literal>BY DEFAULT</literal>
-      determine how the sequence value is given precedence over a
-      user-specified value in an <command>INSERT</command> statement.
-      If <literal>ALWAYS</literal> is specified, a user-specified value is
-      only accepted if the <command>INSERT</command> statement
-      specifies <literal>OVERRIDING SYSTEM VALUE</literal>.  If <literal>BY
-      DEFAULT</literal> is specified, then the user-specified value takes
-      precedence.  See <xref linkend="sql-insert"/> for details.  (In
-      the <command>COPY</command> command, user-specified values are always
-      used regardless of this setting.)
+      determine how explicitly user-specified values are handled in
+      <command>INSERT</command> and <command>UPDATE</command> commands.
+     </para>
+
+     <para>
+      In an <command>INSERT</command> command, if <literal>ALWAYS</literal> is
+      selected, a user-specified value is only accepted if the
+      <command>INSERT</command> statement specifies <literal>OVERRIDING SYSTEM
+      VALUE</literal>.  If <literal>BY DEFAULT</literal> is selected, then the
+      user-specified value takes precedence.  See <xref linkend="sql-insert"/>
+      for details.  (In the <command>COPY</command> command, user-specified
+      values are always used regardless of this setting.)
+     </para>
+
+     <para>
+      In an <command>UPDATE</command> command, if <literal>ALWAYS</literal> is
+      selected, any update of the column to any value other than
+      <literal>DEFAULT</literal> will be rejected.  If <literal>BY
+      DEFAULT</literal> is selected, the column can be updated normally.
+      (There is no <literal>OVERRIDING</literal> clause for the
+      <command>UPDATE</command> command.)
      </para>
 
      <para>
diff --git a/doc/src/sgml/ref/insert.sgml b/doc/src/sgml/ref/insert.sgml
index e829c61642..5662718e3b 100644
--- a/doc/src/sgml/ref/insert.sgml
+++ b/doc/src/sgml/ref/insert.sgml
@@ -206,10 +206,20 @@ <title id="sql-inserting-params-title">Inserting</title>
       <term><literal>OVERRIDING SYSTEM VALUE</literal></term>
       <listitem>
        <para>
-        Without this clause, it is an error to specify an explicit value
-        (other than <literal>DEFAULT</literal>) for an identity column defined
-        as <literal>GENERATED ALWAYS</literal>.  This clause overrides that
-        restriction.
+        If this clause is specified, then any values supplied for identity
+        columns will override the default sequence-generated values.
+       </para>
+
+       <para>
+        For an identity column defined as <literal>GENERATED ALWAYS</literal>,
+        it is an error to insert an explicit value (other than
+        <literal>DEFAULT</literal>) without specifying either
+        <literal>OVERRIDING SYSTEM VALUE</literal> or <literal>OVERRIDING USER
+        VALUE</literal>.  (For an identity column defined as
+        <literal>GENERATED BY DEFAULT</literal>, <literal>OVERRIDING SYSTEM
+        VALUE</literal> is the standard behavior and specifying it does
+        nothing, but <productname>PostgreSQL</productname> allows it as an
+        extension.)
        </para>
       </listitem>
      </varlistentry>
@@ -219,8 +229,8 @@ <title id="sql-inserting-params-title">Inserting</title>
       <listitem>
        <para>
         If this clause is specified, then any values supplied for identity
-        columns defined as <literal>GENERATED BY DEFAULT</literal> are ignored
-        and the default sequence-generated values are applied.
+        columns are ignored and the default sequence-generated values are
+        applied.
        </para>
 
        <para>
@@ -238,7 +248,8 @@ <title id="sql-inserting-params-title">Inserting</title>
       <term><literal>DEFAULT VALUES</literal></term>
       <listitem>
        <para>
-        All columns will be filled with their default values.
+        All columns will be filled with their default values, as if
+        <literal>DEFAULT</literal> were explicitly specified for each column.
         (An <literal>OVERRIDING</literal> clause is not permitted in this
         form.)
        </para>
@@ -258,8 +269,11 @@ <title id="sql-inserting-params-title">Inserting</title>
       <term><literal>DEFAULT</literal></term>
       <listitem>
        <para>
-        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.
        </para>
       </listitem>
      </varlistentry>
diff --git a/doc/src/sgml/ref/update.sgml b/doc/src/sgml/ref/update.sgml
index f58dcd8877..4840bf560c 100644
--- a/doc/src/sgml/ref/update.sgml
+++ b/doc/src/sgml/ref/update.sgml
@@ -142,8 +142,11 @@ <title>Parameters</title>
     <term><literal>DEFAULT</literal></term>
     <listitem>
      <para>
-      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.
      </para>
     </listitem>
    </varlistentry>
diff --git a/src/backend/rewrite/rewriteHandler.c 
b/src/backend/rewrite/rewriteHandler.c
index 3b4f28874a..fe777c3103 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 7322b28765..7ac9df767f 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 b4cdd21bdd..1bf2a976eb 100644
--- a/src/test/regress/sql/identity.sql
+++ b/src/test/regress/sql/identity.sql
@@ -64,25 +64,42 @@ CREATE TABLE itest_err_4 (a serial generated by default as 
identity);
 
 -- 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;
 
 
-- 
2.26.0

Reply via email to