Commit cab5dc5d authored by Robert Haas's avatar Robert Haas

Allow only some columns of a view to be auto-updateable.

Previously, unless all columns were auto-updateable, we wouldn't
inserts, updates, or deletes, or at least not without a rule or trigger;
now, we'll allow inserts and updates that target only the auto-updateable
columns, and deletes even if there are no auto-updateable columns at
all provided the view definition is otherwise suitable.

Dean Rasheed, reviewed by Marko Tiikkaja
parent 523beaa1
...@@ -319,16 +319,8 @@ CREATE VIEW vista AS SELECT text 'Hello World' AS hello; ...@@ -319,16 +319,8 @@ CREATE VIEW vista AS SELECT text 'Hello World' AS hello;
<listitem> <listitem>
<para> <para>
All columns in the view's select list must be simple references to The view's select list must not contain any aggregates, window functions
columns of the underlying relation. They cannot be expressions, or set-returning functions.
literals or functions. System columns cannot be referenced, either.
</para>
</listitem>
<listitem>
<para>
No column of the underlying relation can appear more than once in
the view's select list.
</para> </para>
</listitem> </listitem>
...@@ -340,6 +332,14 @@ CREATE VIEW vista AS SELECT text 'Hello World' AS hello; ...@@ -340,6 +332,14 @@ CREATE VIEW vista AS SELECT text 'Hello World' AS hello;
</itemizedlist> </itemizedlist>
</para> </para>
<para>
An automatically updatable view may contain a mix of updatable and
non-updatable columns. A column is updatable if it is a simple reference
to an updatable column of the underlying base relation; otherwise the
column is read-only, and an error will be raised if an <command>INSERT</>
or <command>UPDATE</> statement attempts to assign a value to it.
</para>
<para> <para>
If the view is automatically updatable the system will convert any If the view is automatically updatable the system will convert any
<command>INSERT</>, <command>UPDATE</> or <command>DELETE</> statement <command>INSERT</>, <command>UPDATE</> or <command>DELETE</> statement
...@@ -434,6 +434,25 @@ CREATE VIEW pg_comedies AS ...@@ -434,6 +434,25 @@ CREATE VIEW pg_comedies AS
<literal>classification</> of new rows. <literal>classification</> of new rows.
</para> </para>
<para>
Create a view with a mix of updatable and non-updatable columns:
<programlisting>
CREATE VIEW comedies AS
SELECT f.*,
country_code_to_name(f.country_code) AS country,
(SELECT avg(r.rating)
FROM user_ratings r
WHERE r.film_id = f.id) AS avg_rating
FROM films f
WHERE f.kind = 'Comedy';
</programlisting>
This view will support <command>INSERT</>, <command>UPDATE</> and
<command>DELETE</>. All the columns from the <literal>films</> table will
be updatable, whereas the computed columns <literal>country</> and
<literal>avg_rating</> will be read-only.
</para>
<para> <para>
Create a recursive view consisting of the numbers from 1 to 100: Create a recursive view consisting of the numbers from 1 to 100:
<programlisting> <programlisting>
......
...@@ -8806,7 +8806,8 @@ ATExecSetRelOptions(Relation rel, List *defList, AlterTableType operation, ...@@ -8806,7 +8806,8 @@ ATExecSetRelOptions(Relation rel, List *defList, AlterTableType operation,
if (check_option) if (check_option)
{ {
const char *view_updatable_error = const char *view_updatable_error =
view_query_is_auto_updatable(view_query, security_barrier); view_query_is_auto_updatable(view_query,
security_barrier, true);
if (view_updatable_error) if (view_updatable_error)
ereport(ERROR, ereport(ERROR,
......
...@@ -469,7 +469,7 @@ DefineView(ViewStmt *stmt, const char *queryString) ...@@ -469,7 +469,7 @@ DefineView(ViewStmt *stmt, const char *queryString)
if (check_option) if (check_option)
{ {
const char *view_updatable_error = const char *view_updatable_error =
view_query_is_auto_updatable(viewParse, security_barrier); view_query_is_auto_updatable(viewParse, security_barrier, true);
if (view_updatable_error) if (view_updatable_error)
ereport(ERROR, ereport(ERROR,
......
This diff is collapsed.
...@@ -20,6 +20,7 @@ ...@@ -20,6 +20,7 @@
#include <math.h> #include <math.h>
#include <unistd.h> #include <unistd.h>
#include "access/sysattr.h"
#include "catalog/catalog.h" #include "catalog/catalog.h"
#include "catalog/pg_tablespace.h" #include "catalog/pg_tablespace.h"
#include "catalog/pg_type.h" #include "catalog/pg_type.h"
...@@ -540,17 +541,13 @@ pg_relation_is_updatable(PG_FUNCTION_ARGS) ...@@ -540,17 +541,13 @@ pg_relation_is_updatable(PG_FUNCTION_ARGS)
Oid reloid = PG_GETARG_OID(0); Oid reloid = PG_GETARG_OID(0);
bool include_triggers = PG_GETARG_BOOL(1); bool include_triggers = PG_GETARG_BOOL(1);
PG_RETURN_INT32(relation_is_updatable(reloid, include_triggers)); PG_RETURN_INT32(relation_is_updatable(reloid, include_triggers, NULL));
} }
/* /*
* pg_column_is_updatable - determine whether a column is updatable * pg_column_is_updatable - determine whether a column is updatable
* *
* Currently we just check whether the column's relation is updatable. * This function encapsulates the decision about just what
* Eventually we might allow views to have some updatable and some
* non-updatable columns.
*
* Also, this function encapsulates the decision about just what
* information_schema.columns.is_updatable actually means. It's not clear * information_schema.columns.is_updatable actually means. It's not clear
* whether deletability of the column's relation should be required, so * whether deletability of the column's relation should be required, so
* we want that decision in C code where we could change it without initdb. * we want that decision in C code where we could change it without initdb.
...@@ -560,6 +557,7 @@ pg_column_is_updatable(PG_FUNCTION_ARGS) ...@@ -560,6 +557,7 @@ pg_column_is_updatable(PG_FUNCTION_ARGS)
{ {
Oid reloid = PG_GETARG_OID(0); Oid reloid = PG_GETARG_OID(0);
AttrNumber attnum = PG_GETARG_INT16(1); AttrNumber attnum = PG_GETARG_INT16(1);
AttrNumber col = attnum - FirstLowInvalidHeapAttributeNumber;
bool include_triggers = PG_GETARG_BOOL(2); bool include_triggers = PG_GETARG_BOOL(2);
int events; int events;
...@@ -567,7 +565,8 @@ pg_column_is_updatable(PG_FUNCTION_ARGS) ...@@ -567,7 +565,8 @@ pg_column_is_updatable(PG_FUNCTION_ARGS)
if (attnum <= 0) if (attnum <= 0)
PG_RETURN_BOOL(false); PG_RETURN_BOOL(false);
events = relation_is_updatable(reloid, include_triggers); events = relation_is_updatable(reloid, include_triggers,
bms_make_singleton(col));
/* We require both updatability and deletability of the relation */ /* We require both updatability and deletability of the relation */
#define REQ_EVENTS ((1 << CMD_UPDATE) | (1 << CMD_DELETE)) #define REQ_EVENTS ((1 << CMD_UPDATE) | (1 << CMD_DELETE))
......
...@@ -22,9 +22,11 @@ extern void AcquireRewriteLocks(Query *parsetree, bool forUpdatePushedDown); ...@@ -22,9 +22,11 @@ extern void AcquireRewriteLocks(Query *parsetree, bool forUpdatePushedDown);
extern Node *build_column_default(Relation rel, int attrno); extern Node *build_column_default(Relation rel, int attrno);
extern Query *get_view_query(Relation view); extern Query *get_view_query(Relation view);
extern const char *view_is_auto_updatable(Relation view);
extern const char *view_query_is_auto_updatable(Query *viewquery, extern const char *view_query_is_auto_updatable(Query *viewquery,
bool security_barrier); bool security_barrier,
extern int relation_is_updatable(Oid reloid, bool include_triggers); bool check_cols);
extern int relation_is_updatable(Oid reloid,
bool include_triggers,
Bitmapset *include_cols);
#endif /* REWRITEHANDLER_H */ #endif /* REWRITEHANDLER_H */
...@@ -2,7 +2,8 @@ ...@@ -2,7 +2,8 @@
-- UPDATABLE VIEWS -- UPDATABLE VIEWS
-- --
-- check that non-updatable views are rejected with useful error messages -- check that non-updatable views and columns are rejected with useful error
-- messages
CREATE TABLE base_tbl (a int PRIMARY KEY, b text DEFAULT 'Unspecified'); CREATE TABLE base_tbl (a int PRIMARY KEY, b text DEFAULT 'Unspecified');
INSERT INTO base_tbl SELECT i, 'Row ' || i FROM generate_series(-2, 2) g(i); INSERT INTO base_tbl SELECT i, 'Row ' || i FROM generate_series(-2, 2) g(i);
...@@ -20,31 +21,33 @@ CREATE VIEW ro_view10 AS SELECT 1 AS a; -- No base relations ...@@ -20,31 +21,33 @@ CREATE VIEW ro_view10 AS SELECT 1 AS a; -- No base relations
CREATE VIEW ro_view11 AS SELECT b1.a, b2.b FROM base_tbl b1, base_tbl b2; -- Multiple base relations CREATE VIEW ro_view11 AS SELECT b1.a, b2.b FROM base_tbl b1, base_tbl b2; -- Multiple base relations
CREATE VIEW ro_view12 AS SELECT * FROM generate_series(1, 10) AS g(a); -- SRF in rangetable CREATE VIEW ro_view12 AS SELECT * FROM generate_series(1, 10) AS g(a); -- SRF in rangetable
CREATE VIEW ro_view13 AS SELECT a, b FROM (SELECT * FROM base_tbl) AS t; -- Subselect in rangetable CREATE VIEW ro_view13 AS SELECT a, b FROM (SELECT * FROM base_tbl) AS t; -- Subselect in rangetable
CREATE VIEW ro_view14 AS SELECT ctid FROM base_tbl; -- System columns not supported CREATE VIEW rw_view14 AS SELECT ctid, a, b FROM base_tbl; -- System columns may be part of an updatable view
CREATE VIEW ro_view15 AS SELECT a, upper(b) FROM base_tbl; -- Expression/function in targetlist CREATE VIEW rw_view15 AS SELECT a, upper(b) FROM base_tbl; -- Expression/function may be part of an updatable view
CREATE VIEW ro_view16 AS SELECT a, b, a AS aa FROM base_tbl; -- Repeated column CREATE VIEW rw_view16 AS SELECT a, b, a AS aa FROM base_tbl; -- Repeated column may be part of an updatable view
CREATE VIEW ro_view17 AS SELECT * FROM ro_view1; -- Base relation not updatable CREATE VIEW ro_view17 AS SELECT * FROM ro_view1; -- Base relation not updatable
CREATE VIEW ro_view18 WITH (security_barrier = true) CREATE VIEW ro_view18 WITH (security_barrier = true)
AS SELECT * FROM base_tbl; -- Security barrier views not updatable AS SELECT * FROM base_tbl; -- Security barrier views not updatable
CREATE VIEW ro_view19 AS SELECT * FROM (VALUES(1)) AS tmp(a); -- VALUES in rangetable CREATE VIEW ro_view19 AS SELECT * FROM (VALUES(1)) AS tmp(a); -- VALUES in rangetable
CREATE SEQUENCE seq; CREATE SEQUENCE seq;
CREATE VIEW ro_view20 AS SELECT * FROM seq; -- View based on a sequence CREATE VIEW ro_view20 AS SELECT * FROM seq; -- View based on a sequence
CREATE VIEW ro_view21 AS SELECT a, b, generate_series(1, a) g FROM base_tbl; -- SRF in targetlist not supported
SELECT table_name, is_insertable_into SELECT table_name, is_insertable_into
FROM information_schema.tables FROM information_schema.tables
WHERE table_name LIKE 'ro_view%' WHERE table_name LIKE E'r_\\_view%'
ORDER BY table_name; ORDER BY table_name;
SELECT table_name, is_updatable, is_insertable_into SELECT table_name, is_updatable, is_insertable_into
FROM information_schema.views FROM information_schema.views
WHERE table_name LIKE 'ro_view%' WHERE table_name LIKE E'r_\\_view%'
ORDER BY table_name; ORDER BY table_name;
SELECT table_name, column_name, is_updatable SELECT table_name, column_name, is_updatable
FROM information_schema.columns FROM information_schema.columns
WHERE table_name LIKE 'ro_view%' WHERE table_name LIKE E'r_\\_view%'
ORDER BY table_name, ordinal_position; ORDER BY table_name, ordinal_position;
-- Read-only views
DELETE FROM ro_view1; DELETE FROM ro_view1;
DELETE FROM ro_view2; DELETE FROM ro_view2;
DELETE FROM ro_view3; DELETE FROM ro_view3;
...@@ -58,13 +61,36 @@ UPDATE ro_view10 SET a=a+1; ...@@ -58,13 +61,36 @@ UPDATE ro_view10 SET a=a+1;
UPDATE ro_view11 SET a=a+1; UPDATE ro_view11 SET a=a+1;
UPDATE ro_view12 SET a=a+1; UPDATE ro_view12 SET a=a+1;
INSERT INTO ro_view13 VALUES (3, 'Row 3'); INSERT INTO ro_view13 VALUES (3, 'Row 3');
INSERT INTO ro_view14 VALUES (null); -- Partially updatable view
INSERT INTO ro_view15 VALUES (3, 'ROW 3'); INSERT INTO rw_view14 VALUES (null, 3, 'Row 3'); -- should fail
INSERT INTO ro_view16 VALUES (3, 'Row 3', 3); INSERT INTO rw_view14 (a, b) VALUES (3, 'Row 3'); -- should be OK
UPDATE rw_view14 SET ctid=null WHERE a=3; -- should fail
UPDATE rw_view14 SET b='ROW 3' WHERE a=3; -- should be OK
SELECT * FROM base_tbl;
DELETE FROM rw_view14 WHERE a=3; -- should be OK
-- Partially updatable view
INSERT INTO rw_view15 VALUES (3, 'ROW 3'); -- should fail
INSERT INTO rw_view15 (a) VALUES (3); -- should be OK
ALTER VIEW rw_view15 ALTER COLUMN upper SET DEFAULT 'NOT SET';
INSERT INTO rw_view15 (a) VALUES (4); -- should fail
UPDATE rw_view15 SET upper='ROW 3' WHERE a=3; -- should fail
UPDATE rw_view15 SET upper=DEFAULT WHERE a=3; -- should fail
UPDATE rw_view15 SET a=4 WHERE a=3; -- should be OK
SELECT * FROM base_tbl;
DELETE FROM rw_view15 WHERE a=4; -- should be OK
-- Partially updatable view
INSERT INTO rw_view16 VALUES (3, 'Row 3', 3); -- should fail
INSERT INTO rw_view16 (a, b) VALUES (3, 'Row 3'); -- should be OK
UPDATE rw_view16 SET a=3, aa=-3 WHERE a=3; -- should fail
UPDATE rw_view16 SET aa=-3 WHERE a=3; -- should be OK
SELECT * FROM base_tbl;
DELETE FROM rw_view16 WHERE a=-3; -- should be OK
-- Read-only views
INSERT INTO ro_view17 VALUES (3, 'ROW 3'); INSERT INTO ro_view17 VALUES (3, 'ROW 3');
INSERT INTO ro_view18 VALUES (3, 'ROW 3'); INSERT INTO ro_view18 VALUES (3, 'ROW 3');
DELETE FROM ro_view19; DELETE FROM ro_view19;
UPDATE ro_view20 SET max_value=1000; UPDATE ro_view20 SET max_value=1000;
UPDATE ro_view21 SET b=upper(b);
DROP TABLE base_tbl CASCADE; DROP TABLE base_tbl CASCADE;
DROP VIEW ro_view10, ro_view12, ro_view19; DROP VIEW ro_view10, ro_view12, ro_view19;
...@@ -510,6 +536,68 @@ SELECT * FROM rw_view1; ...@@ -510,6 +536,68 @@ SELECT * FROM rw_view1;
DROP TABLE base_tbl CASCADE; DROP TABLE base_tbl CASCADE;
-- views with updatable and non-updatable columns
CREATE TABLE base_tbl(a float);
INSERT INTO base_tbl SELECT i/10.0 FROM generate_series(1,10) g(i);
CREATE VIEW rw_view1 AS
SELECT ctid, sin(a) s, a, cos(a) c
FROM base_tbl
WHERE a != 0
ORDER BY abs(a);
INSERT INTO rw_view1 VALUES (null, null, 1.1, null); -- should fail
INSERT INTO rw_view1 (s, c, a) VALUES (null, null, 1.1); -- should fail
INSERT INTO rw_view1 (a) VALUES (1.1) RETURNING a, s, c; -- OK
UPDATE rw_view1 SET s = s WHERE a = 1.1; -- should fail
UPDATE rw_view1 SET a = 1.05 WHERE a = 1.1 RETURNING s; -- OK
DELETE FROM rw_view1 WHERE a = 1.05; -- OK
CREATE VIEW rw_view2 AS
SELECT s, c, s/c t, a base_a, ctid
FROM rw_view1;
INSERT INTO rw_view2 VALUES (null, null, null, 1.1, null); -- should fail
INSERT INTO rw_view2(s, c, base_a) VALUES (null, null, 1.1); -- should fail
INSERT INTO rw_view2(base_a) VALUES (1.1) RETURNING t; -- OK
UPDATE rw_view2 SET s = s WHERE base_a = 1.1; -- should fail
UPDATE rw_view2 SET t = t WHERE base_a = 1.1; -- should fail
UPDATE rw_view2 SET base_a = 1.05 WHERE base_a = 1.1; -- OK
DELETE FROM rw_view2 WHERE base_a = 1.05 RETURNING base_a, s, c, t; -- OK
CREATE VIEW rw_view3 AS
SELECT s, c, s/c t, ctid
FROM rw_view1;
INSERT INTO rw_view3 VALUES (null, null, null, null); -- should fail
INSERT INTO rw_view3(s) VALUES (null); -- should fail
UPDATE rw_view3 SET s = s; -- should fail
DELETE FROM rw_view3 WHERE s = sin(0.1); -- should be OK
SELECT * FROM base_tbl ORDER BY a;
SELECT table_name, is_insertable_into
FROM information_schema.tables
WHERE table_name LIKE E'r_\\_view%'
ORDER BY table_name;
SELECT table_name, is_updatable, is_insertable_into
FROM information_schema.views
WHERE table_name LIKE E'r_\\_view%'
ORDER BY table_name;
SELECT table_name, column_name, is_updatable
FROM information_schema.columns
WHERE table_name LIKE E'r_\\_view%'
ORDER BY table_name, ordinal_position;
SELECT events & 4 != 0 AS upd,
events & 8 != 0 AS ins,
events & 16 != 0 AS del
FROM pg_catalog.pg_relation_is_updatable('rw_view3'::regclass, false) t(events);
DROP TABLE base_tbl CASCADE;
-- inheritance tests -- inheritance tests
CREATE TABLE base_tbl_parent (a int); CREATE TABLE base_tbl_parent (a int);
...@@ -611,7 +699,7 @@ CREATE TABLE base_tbl (a int); ...@@ -611,7 +699,7 @@ CREATE TABLE base_tbl (a int);
CREATE VIEW rw_view1 AS SELECT * FROM base_tbl WITH CHECK OPTION; CREATE VIEW rw_view1 AS SELECT * FROM base_tbl WITH CHECK OPTION;
CREATE VIEW rw_view2 AS SELECT * FROM rw_view1 WHERE a > 0; CREATE VIEW rw_view2 AS SELECT * FROM rw_view1 WHERE a > 0;
CREATE VIEW rw_view3 AS SELECT * FROM rw_view2 WITH CHECK OPTION; CREATE VIEW rw_view3 AS SELECT * FROM rw_view2 WITH CHECK OPTION;
SELECT * FROM information_schema.views WHERE table_name LIKE E'rw\_view_' ORDER BY table_name; SELECT * FROM information_schema.views WHERE table_name LIKE E'rw\\_view_' ORDER BY table_name;
INSERT INTO rw_view1 VALUES (-1); -- ok INSERT INTO rw_view1 VALUES (-1); -- ok
INSERT INTO rw_view1 VALUES (1); -- ok INSERT INTO rw_view1 VALUES (1); -- ok
......
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