From 25fad5800d1f0054effa49e86c081306d9bee7fa Mon Sep 17 00:00:00 2001
From: Gareth Palmer <gareth@internetnz.net.nz>
Date: Fri, 16 Aug 2019 11:56:42 +1200
Subject: [PATCH] Implement INSERT SET syntax

Allow the target column and values of an INSERT statement to be specified
using a SET clause in the same manner as that of an UPDATE statement.

The advantage of using the INSERT SET style is that the columns and values
are kept together, which can make changing or removing a column or value
from a large list easier.

A simple example that uses SET instead of a VALUES() clause:

INSERT INTO t SET c1 = 'foo', c2 = 'bar', c3 = 'baz';

Values may also be sourced from a CTE using a FROM clause:

WITH x AS (
  SELECT 'foo' AS c1, 'bar' AS c2, 'baz' AS c3
)
INSERT INTO t SET c1 = x.c1, c2 = x.c2, c3 = x.c3 FROM x;

INSERT SET is not part of any SQL standard, however this syntax is also
implemented by MySQL. Their implementation does not support specifying a
FROM clause.
---
 doc/src/sgml/ref/insert.sgml                  | 24 ++++++++++-
 src/backend/parser/gram.y                     | 40 ++++++++++++++++++-
 src/backend/parser/parse_expr.c               |  8 +++-
 src/test/regress/expected/insert.out          | 16 ++++++++
 src/test/regress/expected/insert_conflict.out |  2 +
 src/test/regress/expected/with.out            | 21 ++++++++++
 src/test/regress/sql/insert.sql               | 12 ++++++
 src/test/regress/sql/insert_conflict.sql      |  3 ++
 src/test/regress/sql/with.sql                 | 10 +++++
 9 files changed, 132 insertions(+), 4 deletions(-)

diff --git a/doc/src/sgml/ref/insert.sgml b/doc/src/sgml/ref/insert.sgml
index f995a7637f..341616d8b5 100644
--- a/doc/src/sgml/ref/insert.sgml
+++ b/doc/src/sgml/ref/insert.sgml
@@ -24,7 +24,12 @@ PostgreSQL documentation
 [ WITH [ RECURSIVE ] <replaceable class="parameter">with_query</replaceable> [, ...] ]
 INSERT INTO <replaceable class="parameter">table_name</replaceable> [ AS <replaceable class="parameter">alias</replaceable> ] [ ( <replaceable class="parameter">column_name</replaceable> [, ...] ) ]
     [ OVERRIDING { SYSTEM | USER} VALUE ]
-    { DEFAULT VALUES | VALUES ( { <replaceable class="parameter">expression</replaceable> | DEFAULT } [, ...] ) [, ...] | <replaceable class="parameter">query</replaceable> }
+    { DEFAULT VALUES | VALUES ( { <replaceable class="parameter">expression</replaceable> | DEFAULT } [, ...] ) [, ...] |
+      SET { <replaceable class="parameter">column_name</replaceable> = { <replaceable class="parameter">expression</replaceable> | DEFAULT } |
+            ( <replaceable class="parameter">column_name</replaceable> [, ...] ) = [ ROW ] ( { <replaceable class="parameter">expression</replaceable> | DEFAULT } [, ...] ) |
+            ( <replaceable class="parameter">column_name</replaceable> [, ...] ) = ( <replaceable class="parameter">sub-SELECT</replaceable> )
+      } [, ...] [ FROM <replaceable class="parameter">from_list</replaceable> ] } |
+      <replaceable class="parameter">query</replaceable> }
     [ ON CONFLICT [ <replaceable class="parameter">conflict_target</replaceable> ] <replaceable class="parameter">conflict_action</replaceable> ]
     [ RETURNING * | <replaceable class="parameter">output_expression</replaceable> [ [ AS ] <replaceable class="parameter">output_name</replaceable> ] [, ...] ]
 
@@ -254,6 +259,16 @@ INSERT INTO <replaceable class="parameter">table_name</replaceable> [ AS <replac
       </listitem>
      </varlistentry>
 
+     <varlistentry>
+      <term><replaceable class="parameter">from_list</replaceable></term>
+      <listitem>
+       <para>
+        A list of table expressions, allowing columns from other tables
+        to be used as values in the <literal>expression</literal>.
+       </para>
+      </listitem>
+     </varlistentry>
+
      <varlistentry>
       <term><literal>DEFAULT</literal></term>
       <listitem>
@@ -675,6 +690,13 @@ WITH upd AS (
     RETURNING *
 )
 INSERT INTO employees_log SELECT *, current_timestamp FROM upd;
+</programlisting>
+  </para>
+  <para>
+   Insert a single row into table <literal>distributors</literal> using a
+<literal>SET</literal> clause to specify the columns and values:
+<programlisting>
+INSERT INTO distributors SET did = 4, dname = 'Hammers Unlimited, LLC';
 </programlisting>
   </para>
   <para>
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index c97bb367f8..3015a2925a 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -463,7 +463,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
 %type <list>	OptSeqOptList SeqOptList OptParenthesizedSeqOptList
 %type <defelt>	SeqOptElem
 
-%type <istmt>	insert_rest
+%type <istmt>	insert_rest insert_set_clause
 %type <infer>	opt_conf_expr
 %type <onconflict> opt_on_conflict
 
@@ -10892,6 +10892,15 @@ insert_rest:
 					$$->override = $5;
 					$$->selectStmt = $7;
 				}
+			| insert_set_clause
+				{
+					$$ = $1;
+				}
+			| OVERRIDING override_kind VALUE_P insert_set_clause
+				{
+					$$ = $4;
+					$$->override = $2;
+				}
 			| DEFAULT VALUES
 				{
 					$$ = makeNode(InsertStmt);
@@ -10923,6 +10932,35 @@ insert_column_item:
 				}
 		;
 
+insert_set_clause:
+		SET set_clause_list from_clause
+			{
+				SelectStmt *n = makeNode(SelectStmt);
+
+				if ($3 != NULL)
+				{
+					n->targetList = $2;
+					n->fromClause = $3;
+				}
+				else
+				{
+					List *values = NIL;
+					ListCell *col_cell;
+
+					foreach(col_cell, $2)
+					{
+						ResTarget *res_col = (ResTarget *) lfirst(col_cell);
+
+						values = lappend(values, res_col->val);
+					}
+					n->valuesLists = list_make1(values);
+				}
+				$$ = makeNode(InsertStmt);
+				$$->cols = $2;
+				$$->selectStmt = (Node *) n;
+			}
+		;
+
 opt_on_conflict:
 			ON CONFLICT opt_conf_expr DO UPDATE SET set_clause_list	where_clause
 				{
diff --git a/src/backend/parser/parse_expr.c b/src/backend/parser/parse_expr.c
index 76f3dd7076..63ef879447 100644
--- a/src/backend/parser/parse_expr.c
+++ b/src/backend/parser/parse_expr.c
@@ -1566,8 +1566,12 @@ transformMultiAssignRef(ParseState *pstate, MultiAssignRef *maref)
 	Query	   *qtree;
 	TargetEntry *tle;
 
-	/* We should only see this in first-stage processing of UPDATE tlists */
-	Assert(pstate->p_expr_kind == EXPR_KIND_UPDATE_SOURCE);
+	/*
+	 * We should only see this in first-stage processing of UPDATE tlists
+	 * or of an INSERT SET tlist.
+	 */
+	Assert(pstate->p_expr_kind == EXPR_KIND_UPDATE_SOURCE ||
+		   pstate->p_expr_kind == EXPR_KIND_VALUES_SINGLE);
 
 	/* We only need to transform the source if this is the first column */
 	if (maref->colno == 1)
diff --git a/src/test/regress/expected/insert.out b/src/test/regress/expected/insert.out
index 75e25cdf48..c15260ea76 100644
--- a/src/test/regress/expected/insert.out
+++ b/src/test/regress/expected/insert.out
@@ -80,6 +80,22 @@ select col1, col2, char_length(col3) from inserttest;
    30 |   50 |       10000
 (8 rows)
 
+drop table inserttest;
+--
+-- SET test
+--
+create table inserttest (col1 int4, col2 text default 'bar');
+insert into inserttest set col1 = 1, col2 = 'foo';
+insert into inserttest set col1 = 2, col2 = DEFAULT;
+insert into inserttest set (col1, col2) = (3, 'baz');
+select * from inserttest;
+ col1 | col2 
+------+------
+    1 | foo
+    2 | bar
+    3 | baz
+(3 rows)
+
 drop table inserttest;
 --
 -- check indirection (field/array assignment), cf bug #14265
diff --git a/src/test/regress/expected/insert_conflict.out b/src/test/regress/expected/insert_conflict.out
index 1338b2b23e..4d6538b1fb 100644
--- a/src/test/regress/expected/insert_conflict.out
+++ b/src/test/regress/expected/insert_conflict.out
@@ -236,6 +236,8 @@ insert into insertconflicttest values (2, 'Orange') on conflict (key, key, key)
 insert into insertconflicttest
 values (1, 'Apple'), (2, 'Orange')
 on conflict (key) do update set (fruit, key) = (excluded.fruit, excluded.key);
+-- Using insert set syntax
+insert into insertconflicttest set key = 1, fruit = 'Banana' on conflict (key) do update set fruit = excluded.fruit;
 -- Give good diagnostic message when EXCLUDED.* spuriously referenced from
 -- RETURNING:
 insert into insertconflicttest values (1, 'Apple') on conflict (key) do update set fruit = excluded.fruit RETURNING excluded.fruit;
diff --git a/src/test/regress/expected/with.out b/src/test/regress/expected/with.out
index 2a2085556b..b92f9f8a13 100644
--- a/src/test/regress/expected/with.out
+++ b/src/test/regress/expected/with.out
@@ -952,6 +952,27 @@ SELECT * FROM y;
  10
 (10 rows)
 
+DROP TABLE y;
+CREATE TEMPORARY TABLE y (a INTEGER);
+WITH t AS (
+    SELECT generate_series(1, 10) AS a
+)
+INSERT INTO y SET a = t.a+20 FROM t;
+SELECT * FROM y;
+ a  
+----
+ 21
+ 22
+ 23
+ 24
+ 25
+ 26
+ 27
+ 28
+ 29
+ 30
+(10 rows)
+
 DROP TABLE y;
 --
 -- error cases
diff --git a/src/test/regress/sql/insert.sql b/src/test/regress/sql/insert.sql
index 23885f638c..00747e0939 100644
--- a/src/test/regress/sql/insert.sql
+++ b/src/test/regress/sql/insert.sql
@@ -37,6 +37,18 @@ select col1, col2, char_length(col3) from inserttest;
 
 drop table inserttest;
 
+--
+-- SET test
+--
+create table inserttest (col1 int4, col2 text default 'bar');
+insert into inserttest set col1 = 1, col2 = 'foo';
+insert into inserttest set col1 = 2, col2 = DEFAULT;
+insert into inserttest set (col1, col2) = (3, 'baz');
+
+select * from inserttest;
+
+drop table inserttest;
+
 --
 -- check indirection (field/array assignment), cf bug #14265
 --
diff --git a/src/test/regress/sql/insert_conflict.sql b/src/test/regress/sql/insert_conflict.sql
index 43691cd335..e0eb2df0c8 100644
--- a/src/test/regress/sql/insert_conflict.sql
+++ b/src/test/regress/sql/insert_conflict.sql
@@ -97,6 +97,9 @@ insert into insertconflicttest
 values (1, 'Apple'), (2, 'Orange')
 on conflict (key) do update set (fruit, key) = (excluded.fruit, excluded.key);
 
+-- Using insert set syntax
+insert into insertconflicttest set key = 1, fruit = 'Banana' on conflict (key) do update set fruit = excluded.fruit;
+
 -- Give good diagnostic message when EXCLUDED.* spuriously referenced from
 -- RETURNING:
 insert into insertconflicttest values (1, 'Apple') on conflict (key) do update set fruit = excluded.fruit RETURNING excluded.fruit;
diff --git a/src/test/regress/sql/with.sql b/src/test/regress/sql/with.sql
index f85645efde..e6d2e13714 100644
--- a/src/test/regress/sql/with.sql
+++ b/src/test/regress/sql/with.sql
@@ -406,6 +406,16 @@ SELECT * FROM y;
 
 DROP TABLE y;
 
+CREATE TEMPORARY TABLE y (a INTEGER);
+WITH t AS (
+    SELECT generate_series(1, 10) AS a
+)
+INSERT INTO y SET a = t.a+20 FROM t;
+
+SELECT * FROM y;
+
+DROP TABLE y;
+
 --
 -- error cases
 --
-- 
2.17.1

