Commit 17958972 authored by Tom Lane's avatar Tom Lane

Allow a multi-row INSERT to specify DEFAULTs for a generated column.

One can say "INSERT INTO tab(generated_col) VALUES (DEFAULT)" and not
draw an error.  But the equivalent case for a multi-row VALUES list
always threw an error, even if one properly said DEFAULT in each row.
Fix that.  While here, improve the test cases for nearby logic about
OVERRIDING SYSTEM/USER values.

Dean Rasheed

Discussion: https://postgr.es/m/9q0sgcr416t.fsf@gmx.us
parent 9fe649ea
This diff is collapsed.
...@@ -91,17 +91,30 @@ ERROR: for a generated column, GENERATED ALWAYS must be specified ...@@ -91,17 +91,30 @@ ERROR: for a generated column, GENERATED ALWAYS must be specified
LINE 1: ...E gtest_err_8 (a int PRIMARY KEY, b int GENERATED BY DEFAULT... LINE 1: ...E gtest_err_8 (a int PRIMARY KEY, b int GENERATED BY DEFAULT...
^ ^
INSERT INTO gtest1 VALUES (1); INSERT INTO gtest1 VALUES (1);
INSERT INTO gtest1 VALUES (2, DEFAULT); INSERT INTO gtest1 VALUES (2, DEFAULT); -- ok
INSERT INTO gtest1 VALUES (3, 33); -- error INSERT INTO gtest1 VALUES (3, 33); -- error
ERROR: cannot insert into column "b" ERROR: cannot insert into column "b"
DETAIL: Column "b" is a generated column. DETAIL: Column "b" is a generated column.
INSERT INTO gtest1 VALUES (3, 33), (4, 44); -- error
ERROR: cannot insert into column "b"
DETAIL: Column "b" is a generated column.
INSERT INTO gtest1 VALUES (3, DEFAULT), (4, 44); -- error
ERROR: cannot insert into column "b"
DETAIL: Column "b" is a generated column.
INSERT INTO gtest1 VALUES (3, 33), (4, DEFAULT); -- error
ERROR: cannot insert into column "b"
DETAIL: Column "b" is a generated column.
INSERT INTO gtest1 VALUES (3, DEFAULT), (4, DEFAULT); -- ok
SELECT * FROM gtest1 ORDER BY a; SELECT * FROM gtest1 ORDER BY a;
a | b a | b
---+--- ---+---
1 | 2 1 | 2
2 | 4 2 | 4
(2 rows) 3 | 6
4 | 8
(4 rows)
DELETE FROM gtest1 WHERE a >= 3;
UPDATE gtest1 SET b = DEFAULT WHERE a = 1; UPDATE gtest1 SET b = DEFAULT WHERE a = 1;
UPDATE gtest1 SET b = 11 WHERE a = 1; -- error UPDATE gtest1 SET b = 11 WHERE a = 1; -- error
ERROR: column "b" can only be updated to DEFAULT ERROR: column "b" can only be updated to DEFAULT
...@@ -179,9 +192,37 @@ SELECT * FROM gtest1v; ...@@ -179,9 +192,37 @@ SELECT * FROM gtest1v;
3 | 6 3 | 6
(1 row) (1 row)
INSERT INTO gtest1v VALUES (4, 8); -- fails INSERT INTO gtest1v VALUES (4, 8); -- error
ERROR: cannot insert into column "b"
DETAIL: Column "b" is a generated column.
INSERT INTO gtest1v VALUES (5, DEFAULT); -- ok
INSERT INTO gtest1v VALUES (6, 66), (7, 77); -- error
ERROR: cannot insert into column "b"
DETAIL: Column "b" is a generated column.
INSERT INTO gtest1v VALUES (6, DEFAULT), (7, 77); -- error
ERROR: cannot insert into column "b"
DETAIL: Column "b" is a generated column.
INSERT INTO gtest1v VALUES (6, 66), (7, DEFAULT); -- error
ERROR: cannot insert into column "b"
DETAIL: Column "b" is a generated column.
INSERT INTO gtest1v VALUES (6, DEFAULT), (7, DEFAULT); -- ok
ALTER VIEW gtest1v ALTER COLUMN b SET DEFAULT 100;
INSERT INTO gtest1v VALUES (8, DEFAULT); -- error
ERROR: cannot insert into column "b"
DETAIL: Column "b" is a generated column.
INSERT INTO gtest1v VALUES (8, DEFAULT), (9, DEFAULT); -- error
ERROR: cannot insert into column "b" ERROR: cannot insert into column "b"
DETAIL: Column "b" is a generated column. DETAIL: Column "b" is a generated column.
SELECT * FROM gtest1v;
a | b
---+----
3 | 6
5 | 10
6 | 12
7 | 14
(4 rows)
DELETE FROM gtest1v WHERE a >= 5;
DROP VIEW gtest1v; DROP VIEW gtest1v;
-- CTEs -- CTEs
WITH foo AS (SELECT * FROM gtest1) SELECT * FROM foo; WITH foo AS (SELECT * FROM gtest1) SELECT * FROM foo;
......
...@@ -105,6 +105,62 @@ SELECT * FROM itest4; ...@@ -105,6 +105,62 @@ SELECT * FROM itest4;
(2 rows) (2 rows)
-- VALUES RTEs -- VALUES RTEs
CREATE TABLE itest5 (a int generated always as identity, b text);
INSERT INTO itest5 VALUES (1, 'a'); -- error
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 itest5 VALUES (DEFAULT, 'a'); -- ok
INSERT INTO itest5 VALUES (2, 'b'), (3, 'c'); -- error
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 itest5 VALUES (DEFAULT, 'b'), (3, 'c'); -- error
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 itest5 VALUES (2, 'b'), (DEFAULT, 'c'); -- error
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 itest5 VALUES (DEFAULT, 'b'), (DEFAULT, 'c'); -- ok
INSERT INTO itest5 OVERRIDING SYSTEM VALUE VALUES (-1, 'aa');
INSERT INTO itest5 OVERRIDING SYSTEM VALUE VALUES (-2, 'bb'), (-3, 'cc');
INSERT INTO itest5 OVERRIDING SYSTEM VALUE VALUES (DEFAULT, 'dd'), (-4, 'ee');
INSERT INTO itest5 OVERRIDING SYSTEM VALUE VALUES (-5, 'ff'), (DEFAULT, 'gg');
INSERT INTO itest5 OVERRIDING SYSTEM VALUE VALUES (DEFAULT, 'hh'), (DEFAULT, 'ii');
INSERT INTO itest5 OVERRIDING USER VALUE VALUES (-1, 'aaa');
INSERT INTO itest5 OVERRIDING USER VALUE VALUES (-2, 'bbb'), (-3, 'ccc');
INSERT INTO itest5 OVERRIDING USER VALUE VALUES (DEFAULT, 'ddd'), (-4, 'eee');
INSERT INTO itest5 OVERRIDING USER VALUE VALUES (-5, 'fff'), (DEFAULT, 'ggg');
INSERT INTO itest5 OVERRIDING USER VALUE VALUES (DEFAULT, 'hhh'), (DEFAULT, 'iii');
SELECT * FROM itest5;
a | b
----+-----
1 | a
2 | b
3 | c
-1 | aa
-2 | bb
-3 | cc
4 | dd
-4 | ee
-5 | ff
5 | gg
6 | hh
7 | ii
8 | aaa
9 | bbb
10 | ccc
11 | ddd
12 | eee
13 | fff
14 | ggg
15 | hhh
16 | iii
(21 rows)
DROP TABLE itest5;
INSERT INTO itest3 VALUES (DEFAULT, 'a'); INSERT INTO itest3 VALUES (DEFAULT, 'a');
INSERT INTO itest3 VALUES (DEFAULT, 'b'), (DEFAULT, 'c'); INSERT INTO itest3 VALUES (DEFAULT, 'b'), (DEFAULT, 'c');
SELECT * FROM itest3; SELECT * FROM itest3;
......
...@@ -41,10 +41,15 @@ CREATE TABLE gtest_err_7d (a int PRIMARY KEY, b int GENERATED ALWAYS AS (generat ...@@ -41,10 +41,15 @@ CREATE TABLE gtest_err_7d (a int PRIMARY KEY, b int GENERATED ALWAYS AS (generat
CREATE TABLE gtest_err_8 (a int PRIMARY KEY, b int GENERATED BY DEFAULT AS (a * 2) STORED); CREATE TABLE gtest_err_8 (a int PRIMARY KEY, b int GENERATED BY DEFAULT AS (a * 2) STORED);
INSERT INTO gtest1 VALUES (1); INSERT INTO gtest1 VALUES (1);
INSERT INTO gtest1 VALUES (2, DEFAULT); INSERT INTO gtest1 VALUES (2, DEFAULT); -- ok
INSERT INTO gtest1 VALUES (3, 33); -- error INSERT INTO gtest1 VALUES (3, 33); -- error
INSERT INTO gtest1 VALUES (3, 33), (4, 44); -- error
INSERT INTO gtest1 VALUES (3, DEFAULT), (4, 44); -- error
INSERT INTO gtest1 VALUES (3, 33), (4, DEFAULT); -- error
INSERT INTO gtest1 VALUES (3, DEFAULT), (4, DEFAULT); -- ok
SELECT * FROM gtest1 ORDER BY a; SELECT * FROM gtest1 ORDER BY a;
DELETE FROM gtest1 WHERE a >= 3;
UPDATE gtest1 SET b = DEFAULT WHERE a = 1; UPDATE gtest1 SET b = DEFAULT WHERE a = 1;
UPDATE gtest1 SET b = 11 WHERE a = 1; -- error UPDATE gtest1 SET b = 11 WHERE a = 1; -- error
...@@ -75,7 +80,19 @@ SELECT * FROM gtest1 ORDER BY a; ...@@ -75,7 +80,19 @@ SELECT * FROM gtest1 ORDER BY a;
-- views -- views
CREATE VIEW gtest1v AS SELECT * FROM gtest1; CREATE VIEW gtest1v AS SELECT * FROM gtest1;
SELECT * FROM gtest1v; SELECT * FROM gtest1v;
INSERT INTO gtest1v VALUES (4, 8); -- fails INSERT INTO gtest1v VALUES (4, 8); -- error
INSERT INTO gtest1v VALUES (5, DEFAULT); -- ok
INSERT INTO gtest1v VALUES (6, 66), (7, 77); -- error
INSERT INTO gtest1v VALUES (6, DEFAULT), (7, 77); -- error
INSERT INTO gtest1v VALUES (6, 66), (7, DEFAULT); -- error
INSERT INTO gtest1v VALUES (6, DEFAULT), (7, DEFAULT); -- ok
ALTER VIEW gtest1v ALTER COLUMN b SET DEFAULT 100;
INSERT INTO gtest1v VALUES (8, DEFAULT); -- error
INSERT INTO gtest1v VALUES (8, DEFAULT), (9, DEFAULT); -- error
SELECT * FROM gtest1v;
DELETE FROM gtest1v WHERE a >= 5;
DROP VIEW gtest1v; DROP VIEW gtest1v;
-- CTEs -- CTEs
......
...@@ -56,6 +56,29 @@ SELECT * FROM itest4; ...@@ -56,6 +56,29 @@ SELECT * FROM itest4;
-- VALUES RTEs -- VALUES RTEs
CREATE TABLE itest5 (a int generated always as identity, b text);
INSERT INTO itest5 VALUES (1, 'a'); -- error
INSERT INTO itest5 VALUES (DEFAULT, 'a'); -- ok
INSERT INTO itest5 VALUES (2, 'b'), (3, 'c'); -- error
INSERT INTO itest5 VALUES (DEFAULT, 'b'), (3, 'c'); -- error
INSERT INTO itest5 VALUES (2, 'b'), (DEFAULT, 'c'); -- error
INSERT INTO itest5 VALUES (DEFAULT, 'b'), (DEFAULT, 'c'); -- ok
INSERT INTO itest5 OVERRIDING SYSTEM VALUE VALUES (-1, 'aa');
INSERT INTO itest5 OVERRIDING SYSTEM VALUE VALUES (-2, 'bb'), (-3, 'cc');
INSERT INTO itest5 OVERRIDING SYSTEM VALUE VALUES (DEFAULT, 'dd'), (-4, 'ee');
INSERT INTO itest5 OVERRIDING SYSTEM VALUE VALUES (-5, 'ff'), (DEFAULT, 'gg');
INSERT INTO itest5 OVERRIDING SYSTEM VALUE VALUES (DEFAULT, 'hh'), (DEFAULT, 'ii');
INSERT INTO itest5 OVERRIDING USER VALUE VALUES (-1, 'aaa');
INSERT INTO itest5 OVERRIDING USER VALUE VALUES (-2, 'bbb'), (-3, 'ccc');
INSERT INTO itest5 OVERRIDING USER VALUE VALUES (DEFAULT, 'ddd'), (-4, 'eee');
INSERT INTO itest5 OVERRIDING USER VALUE VALUES (-5, 'fff'), (DEFAULT, 'ggg');
INSERT INTO itest5 OVERRIDING USER VALUE VALUES (DEFAULT, 'hhh'), (DEFAULT, 'iii');
SELECT * FROM itest5;
DROP TABLE itest5;
INSERT INTO itest3 VALUES (DEFAULT, 'a'); INSERT INTO itest3 VALUES (DEFAULT, 'a');
INSERT INTO itest3 VALUES (DEFAULT, 'b'), (DEFAULT, 'c'); INSERT INTO itest3 VALUES (DEFAULT, 'b'), (DEFAULT, 'c');
......
Markdown is supported
0% or
You are about to add 0 people to the discussion. Proceed with caution.
Finish editing this message first!
Please register or to comment