Add tests related to GRANT on columns

In a new file `grant_on_table_propagation, added with others
`grant_on_*_propagation` tests.
Only test related to GRANT/REVOKE columns are added here.

Also included several suggestion from comments in the PR.

Testing with real queries leaded to fix the ACL checks used by Citus
(see previous commit)
pull/7918/head
Cédric Villemain 2025-03-10 08:36:46 +01:00
parent 9c0e68f0ef
commit bdb4474319
6 changed files with 730 additions and 5 deletions

View File

@ -0,0 +1,462 @@
--
-- GRANT_ON_TABLE_PROPAGATION
--
SET citus.shard_replication_factor TO 1;
CREATE SCHEMA grant_on_table;
SET search_path TO grant_on_table;
-- create some simple tables: 1 local and 2 managed by citus
-- d ACL must not be updated in anyway.
CREATE TABLE dist_table (id bigint GENERATED BY DEFAULT AS IDENTITY primary key, a int, b text, c int, d text);
SELECT create_distributed_table('grant_on_table.dist_table', 'id');
create_distributed_table
---------------------------------------------------------------------
(1 row)
CREATE TABLE ref_table (id bigint GENERATED BY DEFAULT AS IDENTITY primary key, a int, b text, c int, d text);
SELECT create_reference_table('grant_on_table.ref_table');
create_reference_table
---------------------------------------------------------------------
(1 row)
CREATE TABLE local_table (id int GENERATED BY DEFAULT AS IDENTITY primary key, a int, b text, c int, d text);
\c - - - :worker_1_port
SET search_path TO grant_on_table;
CREATE TABLE local_table (id int GENERATED BY DEFAULT AS IDENTITY primary key, a int, b text, c int, d text);
\c - - - :worker_2_port
SET search_path TO grant_on_table;
CREATE TABLE local_table (id int GENERATED BY DEFAULT AS IDENTITY primary key, a int, b text, c int, d text);
\c - - - :master_port
SET search_path TO grant_on_table;
-- create some users
CREATE USER grant_user_0;
GRANT USAGE ON SCHEMA grant_on_table TO grant_user_0;
CREATE USER grant_user_1;
GRANT USAGE ON SCHEMA grant_on_table TO grant_user_1;
-- this one should not be granted anything:
CREATE USER nogrant_user;
GRANT USAGE ON SCHEMA grant_on_table TO nogrant_user;
--
-- tests related to columns ACL
--
-- test single table, single priv, single col, single user
GRANT SELECT (a) ON ref_table TO grant_user_0;
-- simple check
SET ROLE grant_user_0;
-- ok:
SELECT a FROM grant_on_table.ref_table;
a
---------------------------------------------------------------------
(0 rows)
-- not ok:
SELECT b FROM grant_on_table.ref_table;
ERROR: permission denied for table ref_table
RESET ROLE;
-- test several tables, several distinct priv, several cols, several users
GRANT SELECT (c, b), INSERT (id, a) ON ref_table, dist_table TO grant_user_0, grant_user_1;
-- simple check
SET ROLE grant_user_0;
-- ok:
INSERT INTO grant_on_table.ref_table (a) VALUES (1);
-- not ok:
INSERT INTO grant_on_table.ref_table (b) VALUES (1);
ERROR: permission denied for table ref_table
-- ok:
SELECT a, b, c FROM grant_on_table.ref_table;
a | b | c
---------------------------------------------------------------------
1 | |
(1 row)
SET ROLE grant_user_1;
-- ok:
INSERT INTO grant_on_table.ref_table (a) VALUES (1);
-- not ok:
INSERT INTO grant_on_table.ref_table (b) VALUES (1);
ERROR: permission denied for table ref_table
-- not ok:
SELECT a, b, c FROM grant_on_table.ref_table;
ERROR: permission denied for table ref_table
-- ok:
SELECT b, c FROM grant_on_table.ref_table;
b | c
---------------------------------------------------------------------
|
|
(2 rows)
RESET ROLE;
-- test several tables, several distinct priv, several cols and non cols, several users
GRANT UPDATE (c, b), DELETE ON ref_table TO grant_user_0, grant_user_1;
-- test special case: with system columns (it's ok)
GRANT INSERT (ctid, xmin, b) ON ref_table TO grant_user_0;
-- simple check
SET ROLE grant_user_0;
-- ok:
INSERT INTO grant_on_table.ref_table (b) VALUES (1);
-- ok:
UPDATE grant_on_table.ref_table SET b = 3;
-- not ok:
UPDATE grant_on_table.ref_table SET d = 3;
ERROR: permission denied for table ref_table
DELETE FROM grant_on_table.ref_table;
RESET ROLE;
-- test special case: ALL
GRANT ALL (id) ON ref_table TO grant_user_0;
GRANT ALL (id, c) ON ref_table TO grant_user_1;
-- simple check
SET ROLE grant_user_1;
-- we've just granted INSERT ON c with ALL
-- ok:
INSERT INTO grant_on_table.ref_table (c) VALUES (3);
-- still not ok:
INSERT INTO grant_on_table.ref_table (d) VALUES (3);
ERROR: permission denied for table ref_table
-- ok:
SELECT id,c FROM grant_on_table.ref_table;
id | c
---------------------------------------------------------------------
4 | 3
(1 row)
DELETE FROM grant_on_table.ref_table;
RESET ROLE;
-- ALL cannot be mixed with other privs
GRANT SELECT (d), ALL (d) ON ref_table TO nogrant_user;
ERROR: syntax error at or near "ALL"
GRANT ALL (d), SELECT (d) ON ref_table TO nogrant_user;
ERROR: syntax error at or near ","
-- simple check before the next test
SET ROLE grant_user_1;
-- we've just granted SELECT id on ALL TABLES
-- not ok:
SELECT id
FROM grant_on_table.ref_table
UNION ALL
SELECT id
FROM grant_on_table.dist_table
UNION ALL
SELECT id
FROM grant_on_table.local_table;
ERROR: permission denied for table dist_table
RESET ROLE;
-- test special case: ALL TABLES IN SCHEMA is not supposed to be correct
-- but is accepted by PostgreSQL - non documented feature
GRANT SELECT (id) ON ALL TABLES IN SCHEMA grant_on_table TO grant_user_1;
-- simple check
SET ROLE grant_user_1;
-- we've just granted SELECT id on ALL TABLES
-- ok:
SELECT id
FROM grant_on_table.ref_table
UNION ALL
SELECT id
FROM grant_on_table.dist_table
UNION ALL
SELECT id
FROM grant_on_table.local_table;
id
---------------------------------------------------------------------
(0 rows)
RESET ROLE;
-- test special case: TRUNCATE and some others are not correct, here mixed with correct
GRANT TRUNCATE (b, a), SELECT (d) ON ref_table TO nogrant_user;
ERROR: invalid privilege type TRUNCATE for column
-- check non propagation for local table
GRANT UPDATE (id) ON local_table TO grant_user_0;
-- special case: mixed with distributed table:
GRANT INSERT (b, c) ON local_table, dist_table TO grant_user_1;
-- simple check
SET ROLE grant_user_1;
-- ok:
INSERT INTO grant_on_table.dist_table (b, c) VALUES ('ok', 1);
RESET ROLE;
-- check on coordinator and workers
SELECT relname, relacl FROM pg_class
WHERE relname IN ('dist_table', 'ref_table', 'local_table') ORDER BY 1;
relname | relacl
---------------------------------------------------------------------
dist_table |
local_table |
ref_table | {postgres=arwdDxt/postgres,grant_user_0=d/postgres,grant_user_1=d/postgres}
(3 rows)
SELECT attrelid::regclass, attname, attacl FROM pg_attribute
WHERE attrelid IN ('dist_table'::regclass, 'ref_table'::regclass, 'local_table'::regclass)
AND attacl IS NOT NULL
ORDER BY 1, 2;
attrelid | attname | attacl
---------------------------------------------------------------------
dist_table | a | {grant_user_0=a/postgres,grant_user_1=a/postgres}
dist_table | b | {grant_user_0=r/postgres,grant_user_1=ar/postgres}
dist_table | c | {grant_user_0=r/postgres,grant_user_1=ar/postgres}
dist_table | id | {grant_user_0=a/postgres,grant_user_1=ar/postgres}
ref_table | a | {grant_user_0=ar/postgres,grant_user_1=a/postgres}
ref_table | b | {grant_user_0=arw/postgres,grant_user_1=rw/postgres}
ref_table | c | {grant_user_0=rw/postgres,grant_user_1=arwx/postgres}
ref_table | ctid | {grant_user_0=a/postgres}
ref_table | id | {grant_user_0=arwx/postgres,grant_user_1=arwx/postgres}
ref_table | xmin | {grant_user_0=a/postgres}
local_table | b | {grant_user_1=a/postgres}
local_table | c | {grant_user_1=a/postgres}
local_table | id | {grant_user_1=r/postgres,grant_user_0=w/postgres}
(13 rows)
\c - - - :worker_1_port
SET search_path TO grant_on_table;
SELECT relname, relacl FROM pg_class
WHERE relname IN ('dist_table', 'ref_table', 'local_table') ORDER BY 1;
relname | relacl
---------------------------------------------------------------------
dist_table |
local_table |
ref_table | {postgres=arwdDxt/postgres,grant_user_0=d/postgres,grant_user_1=d/postgres}
(3 rows)
SELECT attrelid::regclass, attname, attacl FROM pg_attribute
WHERE attrelid IN ('dist_table'::regclass, 'ref_table'::regclass, 'local_table'::regclass)
AND attacl IS NOT NULL
ORDER BY 1, 2;
attrelid | attname | attacl
---------------------------------------------------------------------
dist_table | a | {grant_user_0=a/postgres,grant_user_1=a/postgres}
dist_table | b | {grant_user_0=r/postgres,grant_user_1=ar/postgres}
dist_table | c | {grant_user_0=r/postgres,grant_user_1=ar/postgres}
dist_table | id | {grant_user_0=a/postgres,grant_user_1=ar/postgres}
ref_table | a | {grant_user_0=ar/postgres,grant_user_1=a/postgres}
ref_table | b | {grant_user_0=arw/postgres,grant_user_1=rw/postgres}
ref_table | c | {grant_user_0=rw/postgres,grant_user_1=arwx/postgres}
ref_table | ctid | {grant_user_0=a/postgres}
ref_table | id | {grant_user_0=arwx/postgres,grant_user_1=arwx/postgres}
ref_table | xmin | {grant_user_0=a/postgres}
(10 rows)
\c - - - :worker_2_port
SET search_path TO grant_on_table;
SELECT relname, relacl FROM pg_class
WHERE relname IN ('dist_table', 'ref_table', 'local_table') ORDER BY 1;
relname | relacl
---------------------------------------------------------------------
dist_table |
local_table |
ref_table | {postgres=arwdDxt/postgres,grant_user_0=d/postgres,grant_user_1=d/postgres}
(3 rows)
SELECT attrelid::regclass, attname, attacl FROM pg_attribute
WHERE attrelid IN ('dist_table'::regclass, 'ref_table'::regclass, 'local_table'::regclass)
AND attacl IS NOT NULL
ORDER BY 1, 2;
attrelid | attname | attacl
---------------------------------------------------------------------
dist_table | a | {grant_user_0=a/postgres,grant_user_1=a/postgres}
dist_table | b | {grant_user_0=r/postgres,grant_user_1=ar/postgres}
dist_table | c | {grant_user_0=r/postgres,grant_user_1=ar/postgres}
dist_table | id | {grant_user_0=a/postgres,grant_user_1=ar/postgres}
ref_table | a | {grant_user_0=ar/postgres,grant_user_1=a/postgres}
ref_table | b | {grant_user_0=arw/postgres,grant_user_1=rw/postgres}
ref_table | c | {grant_user_0=rw/postgres,grant_user_1=arwx/postgres}
ref_table | ctid | {grant_user_0=a/postgres}
ref_table | id | {grant_user_0=arwx/postgres,grant_user_1=arwx/postgres}
ref_table | xmin | {grant_user_0=a/postgres}
(10 rows)
\c - - - :master_port
SET search_path TO grant_on_table;
-- revoke, for columns it's the same logic so we don't bother testing combinations
REVOKE SELECT(id, a) ON ref_table, dist_table, local_table FROM grant_user_0, grant_user_1;
-- simple check
SET ROLE grant_user_0;
-- not ok:
SELECT a FROM grant_on_table.ref_table;
ERROR: permission denied for table ref_table
RESET ROLE;
REVOKE ALL(id, b) ON ref_table, dist_table, local_table from grant_user_0, grant_user_1;
-- simple check
SET ROLE grant_user_0;
-- not ok:
SELECT b FROM grant_on_table.ref_table;
ERROR: permission denied for table ref_table
RESET ROLE;
-- check on coordinator and workers
SELECT relname, relacl FROM pg_class
WHERE relname IN ('dist_table', 'ref_table', 'local_table') ORDER BY 1;
relname | relacl
---------------------------------------------------------------------
dist_table |
local_table |
ref_table | {postgres=arwdDxt/postgres,grant_user_0=d/postgres,grant_user_1=d/postgres}
(3 rows)
SELECT attrelid::regclass, attname, attacl FROM pg_attribute
WHERE attrelid IN ('dist_table'::regclass, 'ref_table'::regclass, 'local_table'::regclass)
AND attacl IS NOT NULL
ORDER BY 1, 2;
attrelid | attname | attacl
---------------------------------------------------------------------
dist_table | a | {grant_user_0=a/postgres,grant_user_1=a/postgres}
dist_table | c | {grant_user_0=r/postgres,grant_user_1=ar/postgres}
ref_table | a | {grant_user_0=a/postgres,grant_user_1=a/postgres}
ref_table | c | {grant_user_0=rw/postgres,grant_user_1=arwx/postgres}
ref_table | ctid | {grant_user_0=a/postgres}
ref_table | xmin | {grant_user_0=a/postgres}
local_table | c | {grant_user_1=a/postgres}
(7 rows)
\c - - - :worker_1_port
SET search_path TO grant_on_table;
SELECT relname, relacl FROM pg_class
WHERE relname IN ('dist_table', 'ref_table', 'local_table') ORDER BY 1;
relname | relacl
---------------------------------------------------------------------
dist_table |
local_table |
ref_table | {postgres=arwdDxt/postgres,grant_user_0=d/postgres,grant_user_1=d/postgres}
(3 rows)
SELECT attrelid::regclass, attname, attacl FROM pg_attribute
WHERE attrelid IN ('dist_table'::regclass, 'ref_table'::regclass, 'local_table'::regclass)
AND attacl IS NOT NULL
ORDER BY 1, 2;
attrelid | attname | attacl
---------------------------------------------------------------------
dist_table | a | {grant_user_0=a/postgres,grant_user_1=a/postgres}
dist_table | c | {grant_user_0=r/postgres,grant_user_1=ar/postgres}
ref_table | a | {grant_user_0=a/postgres,grant_user_1=a/postgres}
ref_table | c | {grant_user_0=rw/postgres,grant_user_1=arwx/postgres}
ref_table | ctid | {grant_user_0=a/postgres}
ref_table | xmin | {grant_user_0=a/postgres}
(6 rows)
\c - - - :worker_2_port
SET search_path TO grant_on_table;
SELECT relname, relacl FROM pg_class
WHERE relname IN ('dist_table', 'ref_table', 'local_table') ORDER BY 1;
relname | relacl
---------------------------------------------------------------------
dist_table |
local_table |
ref_table | {postgres=arwdDxt/postgres,grant_user_0=d/postgres,grant_user_1=d/postgres}
(3 rows)
SELECT attrelid::regclass, attname, attacl FROM pg_attribute
WHERE attrelid IN ('dist_table'::regclass, 'ref_table'::regclass, 'local_table'::regclass)
AND attacl IS NOT NULL
ORDER BY 1, 2;
attrelid | attname | attacl
---------------------------------------------------------------------
dist_table | a | {grant_user_0=a/postgres,grant_user_1=a/postgres}
dist_table | c | {grant_user_0=r/postgres,grant_user_1=ar/postgres}
ref_table | a | {grant_user_0=a/postgres,grant_user_1=a/postgres}
ref_table | c | {grant_user_0=rw/postgres,grant_user_1=arwx/postgres}
ref_table | ctid | {grant_user_0=a/postgres}
ref_table | xmin | {grant_user_0=a/postgres}
(6 rows)
-- and test from a worker
\c - - - :worker_1_port
SET search_path TO grant_on_table;
GRANT SELECT (a, b) ON ref_table TO grant_user_0;
-- check on coordinator and workers
\c - - - :master_port
SET search_path TO grant_on_table;
SELECT relname, relacl FROM pg_class
WHERE relname IN ('dist_table', 'ref_table', 'local_table') ORDER BY 1;
relname | relacl
---------------------------------------------------------------------
dist_table |
local_table |
ref_table | {postgres=arwdDxt/postgres,grant_user_0=d/postgres,grant_user_1=d/postgres}
(3 rows)
SELECT attrelid::regclass, attname, attacl FROM pg_attribute
WHERE attrelid IN ('dist_table'::regclass, 'ref_table'::regclass, 'local_table'::regclass)
AND attacl IS NOT NULL
ORDER BY 1, 2;
attrelid | attname | attacl
---------------------------------------------------------------------
dist_table | a | {grant_user_0=a/postgres,grant_user_1=a/postgres}
dist_table | c | {grant_user_0=r/postgres,grant_user_1=ar/postgres}
ref_table | a | {grant_user_0=a/postgres,grant_user_1=a/postgres}
ref_table | c | {grant_user_0=rw/postgres,grant_user_1=arwx/postgres}
ref_table | ctid | {grant_user_0=a/postgres}
ref_table | xmin | {grant_user_0=a/postgres}
local_table | c | {grant_user_1=a/postgres}
(7 rows)
\c - - - :worker_1_port
SET search_path TO grant_on_table;
SELECT relname, relacl FROM pg_class
WHERE relname IN ('dist_table', 'ref_table', 'local_table') ORDER BY 1;
relname | relacl
---------------------------------------------------------------------
dist_table |
local_table |
ref_table | {postgres=arwdDxt/postgres,grant_user_0=d/postgres,grant_user_1=d/postgres}
(3 rows)
SELECT attrelid::regclass, attname, attacl FROM pg_attribute
WHERE attrelid IN ('dist_table'::regclass, 'ref_table'::regclass, 'local_table'::regclass)
AND attacl IS NOT NULL
ORDER BY 1, 2;
attrelid | attname | attacl
---------------------------------------------------------------------
dist_table | a | {grant_user_0=a/postgres,grant_user_1=a/postgres}
dist_table | c | {grant_user_0=r/postgres,grant_user_1=ar/postgres}
ref_table | a | {grant_user_0=a/postgres,grant_user_1=a/postgres}
ref_table | c | {grant_user_0=rw/postgres,grant_user_1=arwx/postgres}
ref_table | ctid | {grant_user_0=a/postgres}
ref_table | xmin | {grant_user_0=a/postgres}
(6 rows)
\c - - - :worker_2_port
SET search_path TO grant_on_table;
SELECT relname, relacl FROM pg_class
WHERE relname IN ('dist_table', 'ref_table', 'local_table') ORDER BY 1;
relname | relacl
---------------------------------------------------------------------
dist_table |
local_table |
ref_table | {postgres=arwdDxt/postgres,grant_user_0=d/postgres,grant_user_1=d/postgres}
(3 rows)
SELECT attrelid::regclass, attname, attacl FROM pg_attribute
WHERE attrelid IN ('dist_table'::regclass, 'ref_table'::regclass, 'local_table'::regclass)
AND attacl IS NOT NULL
ORDER BY 1, 2;
attrelid | attname | attacl
---------------------------------------------------------------------
dist_table | a | {grant_user_0=a/postgres,grant_user_1=a/postgres}
dist_table | c | {grant_user_0=r/postgres,grant_user_1=ar/postgres}
ref_table | a | {grant_user_0=a/postgres,grant_user_1=a/postgres}
ref_table | c | {grant_user_0=rw/postgres,grant_user_1=arwx/postgres}
ref_table | ctid | {grant_user_0=a/postgres}
ref_table | xmin | {grant_user_0=a/postgres}
(6 rows)
\c - - - :master_port
SET search_path TO grant_on_table;
-- cleanup
REVOKE ALL ON ref_table, dist_table, local_table from grant_user_0, grant_user_1;
-- and try some WITH GRANT OPTION
GRANT ALL(id, b) ON ref_table TO grant_user_0 WITH GRANT OPTION;
SET ROLE grant_user_0;
GRANT ALL(id, b) ON grant_on_table.ref_table TO grant_user_1;
SET ROLE grant_user_1;
INSERT INTO grant_on_table.ref_table (b) VALUES ('OK');
SELECT id, b FROM grant_on_table.ref_table;
id | b
---------------------------------------------------------------------
5 | OK
(1 row)
RESET ROLE;
-- cleanup
-- prevent useless messages on DROP objects.
SET client_min_messages TO ERROR;
DROP SCHEMA grant_on_table CASCADE;
DROP ROLE grant_user_0, grant_user_1, nogrant_user;
RESET client_min_messages;
RESET search_path;

View File

@ -313,9 +313,8 @@ SELECT * FROM trivial_full_access ORDER BY id;
(4 rows)
RESET ROLE;
-- verify column level grants are not supported
-- verify column level grants are supported
GRANT UPDATE (id) ON trivial_postgres TO read_access;
ERROR: grant/revoke on column list is currently unsupported
DROP TABLE trivial_full_access;
DROP TABLE trivial_postgres;
DROP TABLE stage_full_access;

View File

@ -304,9 +304,8 @@ SELECT * FROM trivial_full_access ORDER BY id;
(4 rows)
RESET ROLE;
-- verify column level grants are not supported
-- verify column level grants are supported
GRANT UPDATE (id) ON trivial_postgres TO read_access;
ERROR: grant/revoke on column list is currently unsupported
DROP TABLE trivial_full_access;
DROP TABLE trivial_postgres;
DROP TABLE stage_full_access;

View File

@ -49,6 +49,7 @@ test: multi_test_catalog_views
test: multi_table_ddl
test: multi_alias
test: multi_sequence_default
test: grant_on_table_propagation
test: grant_on_sequence_propagation
test: multi_name_lengths
test: multi_name_resolution

View File

@ -0,0 +1,264 @@
--
-- GRANT_ON_TABLE_PROPAGATION
--
SET citus.shard_replication_factor TO 1;
CREATE SCHEMA grant_on_table;
SET search_path TO grant_on_table;
-- create some simple tables: 1 local and 2 managed by citus
-- d ACL must not be updated in anyway.
CREATE TABLE dist_table (id bigint GENERATED BY DEFAULT AS IDENTITY primary key, a int, b text, c int, d text);
SELECT create_distributed_table('grant_on_table.dist_table', 'id');
CREATE TABLE ref_table (id bigint GENERATED BY DEFAULT AS IDENTITY primary key, a int, b text, c int, d text);
SELECT create_reference_table('grant_on_table.ref_table');
CREATE TABLE local_table (id int GENERATED BY DEFAULT AS IDENTITY primary key, a int, b text, c int, d text);
\c - - - :worker_1_port
SET search_path TO grant_on_table;
CREATE TABLE local_table (id int GENERATED BY DEFAULT AS IDENTITY primary key, a int, b text, c int, d text);
\c - - - :worker_2_port
SET search_path TO grant_on_table;
CREATE TABLE local_table (id int GENERATED BY DEFAULT AS IDENTITY primary key, a int, b text, c int, d text);
\c - - - :master_port
SET search_path TO grant_on_table;
-- create some users
CREATE USER grant_user_0;
GRANT USAGE ON SCHEMA grant_on_table TO grant_user_0;
CREATE USER grant_user_1;
GRANT USAGE ON SCHEMA grant_on_table TO grant_user_1;
-- this one should not be granted anything:
CREATE USER nogrant_user;
GRANT USAGE ON SCHEMA grant_on_table TO nogrant_user;
--
-- tests related to columns ACL
--
-- test single table, single priv, single col, single user
GRANT SELECT (a) ON ref_table TO grant_user_0;
-- simple check
SET ROLE grant_user_0;
-- ok:
SELECT a FROM grant_on_table.ref_table;
-- not ok:
SELECT b FROM grant_on_table.ref_table;
RESET ROLE;
-- test several tables, several distinct priv, several cols, several users
GRANT SELECT (c, b), INSERT (id, a) ON ref_table, dist_table TO grant_user_0, grant_user_1;
-- simple check
SET ROLE grant_user_0;
-- ok:
INSERT INTO grant_on_table.ref_table (a) VALUES (1);
-- not ok:
INSERT INTO grant_on_table.ref_table (b) VALUES (1);
-- ok:
SELECT a, b, c FROM grant_on_table.ref_table;
SET ROLE grant_user_1;
-- ok:
INSERT INTO grant_on_table.ref_table (a) VALUES (1);
-- not ok:
INSERT INTO grant_on_table.ref_table (b) VALUES (1);
-- not ok:
SELECT a, b, c FROM grant_on_table.ref_table;
-- ok:
SELECT b, c FROM grant_on_table.ref_table;
RESET ROLE;
-- test several tables, several distinct priv, several cols and non cols, several users
GRANT UPDATE (c, b), DELETE ON ref_table TO grant_user_0, grant_user_1;
-- test special case: with system columns (it's ok)
GRANT INSERT (ctid, xmin, b) ON ref_table TO grant_user_0;
-- simple check
SET ROLE grant_user_0;
-- ok:
INSERT INTO grant_on_table.ref_table (b) VALUES (1);
-- ok:
UPDATE grant_on_table.ref_table SET b = 3;
-- not ok:
UPDATE grant_on_table.ref_table SET d = 3;
DELETE FROM grant_on_table.ref_table;
RESET ROLE;
-- test special case: ALL
GRANT ALL (id) ON ref_table TO grant_user_0;
GRANT ALL (id, c) ON ref_table TO grant_user_1;
-- simple check
SET ROLE grant_user_1;
-- we've just granted INSERT ON c with ALL
-- ok:
INSERT INTO grant_on_table.ref_table (c) VALUES (3);
-- still not ok:
INSERT INTO grant_on_table.ref_table (d) VALUES (3);
-- ok:
SELECT id,c FROM grant_on_table.ref_table;
DELETE FROM grant_on_table.ref_table;
RESET ROLE;
-- ALL cannot be mixed with other privs
GRANT SELECT (d), ALL (d) ON ref_table TO nogrant_user;
GRANT ALL (d), SELECT (d) ON ref_table TO nogrant_user;
-- simple check before the next test
SET ROLE grant_user_1;
-- we've just granted SELECT id on ALL TABLES
-- not ok:
SELECT id
FROM grant_on_table.ref_table
UNION ALL
SELECT id
FROM grant_on_table.dist_table
UNION ALL
SELECT id
FROM grant_on_table.local_table;
RESET ROLE;
-- test special case: ALL TABLES IN SCHEMA is not supposed to be correct
-- but is accepted by PostgreSQL - non documented feature
GRANT SELECT (id) ON ALL TABLES IN SCHEMA grant_on_table TO grant_user_1;
-- simple check
SET ROLE grant_user_1;
-- we've just granted SELECT id on ALL TABLES
-- ok:
SELECT id
FROM grant_on_table.ref_table
UNION ALL
SELECT id
FROM grant_on_table.dist_table
UNION ALL
SELECT id
FROM grant_on_table.local_table;
RESET ROLE;
-- test special case: TRUNCATE and some others are not correct, here mixed with correct
GRANT TRUNCATE (b, a), SELECT (d) ON ref_table TO nogrant_user;
-- check non propagation for local table
GRANT UPDATE (id) ON local_table TO grant_user_0;
-- special case: mixed with distributed table:
GRANT INSERT (b, c) ON local_table, dist_table TO grant_user_1;
-- simple check
SET ROLE grant_user_1;
-- ok:
INSERT INTO grant_on_table.dist_table (b, c) VALUES ('ok', 1);
RESET ROLE;
-- check on coordinator and workers
SELECT relname, relacl FROM pg_class
WHERE relname IN ('dist_table', 'ref_table', 'local_table') ORDER BY 1;
SELECT attrelid::regclass, attname, attacl FROM pg_attribute
WHERE attrelid IN ('dist_table'::regclass, 'ref_table'::regclass, 'local_table'::regclass)
AND attacl IS NOT NULL
ORDER BY 1, 2;
\c - - - :worker_1_port
SET search_path TO grant_on_table;
SELECT relname, relacl FROM pg_class
WHERE relname IN ('dist_table', 'ref_table', 'local_table') ORDER BY 1;
SELECT attrelid::regclass, attname, attacl FROM pg_attribute
WHERE attrelid IN ('dist_table'::regclass, 'ref_table'::regclass, 'local_table'::regclass)
AND attacl IS NOT NULL
ORDER BY 1, 2;
\c - - - :worker_2_port
SET search_path TO grant_on_table;
SELECT relname, relacl FROM pg_class
WHERE relname IN ('dist_table', 'ref_table', 'local_table') ORDER BY 1;
SELECT attrelid::regclass, attname, attacl FROM pg_attribute
WHERE attrelid IN ('dist_table'::regclass, 'ref_table'::regclass, 'local_table'::regclass)
AND attacl IS NOT NULL
ORDER BY 1, 2;
\c - - - :master_port
SET search_path TO grant_on_table;
-- revoke, for columns it's the same logic so we don't bother testing combinations
REVOKE SELECT(id, a) ON ref_table, dist_table, local_table FROM grant_user_0, grant_user_1;
-- simple check
SET ROLE grant_user_0;
-- not ok:
SELECT a FROM grant_on_table.ref_table;
RESET ROLE;
REVOKE ALL(id, b) ON ref_table, dist_table, local_table from grant_user_0, grant_user_1;
-- simple check
SET ROLE grant_user_0;
-- not ok:
SELECT b FROM grant_on_table.ref_table;
RESET ROLE;
-- check on coordinator and workers
SELECT relname, relacl FROM pg_class
WHERE relname IN ('dist_table', 'ref_table', 'local_table') ORDER BY 1;
SELECT attrelid::regclass, attname, attacl FROM pg_attribute
WHERE attrelid IN ('dist_table'::regclass, 'ref_table'::regclass, 'local_table'::regclass)
AND attacl IS NOT NULL
ORDER BY 1, 2;
\c - - - :worker_1_port
SET search_path TO grant_on_table;
SELECT relname, relacl FROM pg_class
WHERE relname IN ('dist_table', 'ref_table', 'local_table') ORDER BY 1;
SELECT attrelid::regclass, attname, attacl FROM pg_attribute
WHERE attrelid IN ('dist_table'::regclass, 'ref_table'::regclass, 'local_table'::regclass)
AND attacl IS NOT NULL
ORDER BY 1, 2;
\c - - - :worker_2_port
SET search_path TO grant_on_table;
SELECT relname, relacl FROM pg_class
WHERE relname IN ('dist_table', 'ref_table', 'local_table') ORDER BY 1;
SELECT attrelid::regclass, attname, attacl FROM pg_attribute
WHERE attrelid IN ('dist_table'::regclass, 'ref_table'::regclass, 'local_table'::regclass)
AND attacl IS NOT NULL
ORDER BY 1, 2;
-- and test from a worker
\c - - - :worker_1_port
SET search_path TO grant_on_table;
GRANT SELECT (a, b) ON ref_table TO grant_user_0;
-- check on coordinator and workers
\c - - - :master_port
SET search_path TO grant_on_table;
SELECT relname, relacl FROM pg_class
WHERE relname IN ('dist_table', 'ref_table', 'local_table') ORDER BY 1;
SELECT attrelid::regclass, attname, attacl FROM pg_attribute
WHERE attrelid IN ('dist_table'::regclass, 'ref_table'::regclass, 'local_table'::regclass)
AND attacl IS NOT NULL
ORDER BY 1, 2;
\c - - - :worker_1_port
SET search_path TO grant_on_table;
SELECT relname, relacl FROM pg_class
WHERE relname IN ('dist_table', 'ref_table', 'local_table') ORDER BY 1;
SELECT attrelid::regclass, attname, attacl FROM pg_attribute
WHERE attrelid IN ('dist_table'::regclass, 'ref_table'::regclass, 'local_table'::regclass)
AND attacl IS NOT NULL
ORDER BY 1, 2;
\c - - - :worker_2_port
SET search_path TO grant_on_table;
SELECT relname, relacl FROM pg_class
WHERE relname IN ('dist_table', 'ref_table', 'local_table') ORDER BY 1;
SELECT attrelid::regclass, attname, attacl FROM pg_attribute
WHERE attrelid IN ('dist_table'::regclass, 'ref_table'::regclass, 'local_table'::regclass)
AND attacl IS NOT NULL
ORDER BY 1, 2;
\c - - - :master_port
SET search_path TO grant_on_table;
-- cleanup
REVOKE ALL ON ref_table, dist_table, local_table from grant_user_0, grant_user_1;
-- and try some WITH GRANT OPTION
GRANT ALL(id, b) ON ref_table TO grant_user_0 WITH GRANT OPTION;
SET ROLE grant_user_0;
GRANT ALL(id, b) ON grant_on_table.ref_table TO grant_user_1;
SET ROLE grant_user_1;
INSERT INTO grant_on_table.ref_table (b) VALUES ('OK');
SELECT id, b FROM grant_on_table.ref_table;
RESET ROLE;
-- cleanup
-- prevent useless messages on DROP objects.
SET client_min_messages TO ERROR;
DROP SCHEMA grant_on_table CASCADE;
DROP ROLE grant_user_0, grant_user_1, nogrant_user;
RESET client_min_messages;
RESET search_path;

View File

@ -121,7 +121,7 @@ SELECT * FROM trivial_postgres ORDER BY id;
SELECT * FROM trivial_full_access ORDER BY id;
RESET ROLE;
-- verify column level grants are not supported
-- verify column level grants are supported
GRANT UPDATE (id) ON trivial_postgres TO read_access;
DROP TABLE trivial_full_access;