mirror of https://github.com/citusdata/citus.git
Rework grant on table test
I applied suggestion from @eaydingol to check acl more often during the tests. Also simplifed and used more accurate attribute namespull/7918/head
parent
bc30ffa901
commit
6e4d3bdf47
File diff suppressed because it is too large
Load Diff
File diff suppressed because it is too large
Load Diff
|
@ -11,22 +11,32 @@ SET citus.shard_replication_factor TO 1;
|
||||||
CREATE SCHEMA grant_on_table;
|
CREATE SCHEMA grant_on_table;
|
||||||
SET search_path TO grant_on_table;
|
SET search_path TO grant_on_table;
|
||||||
|
|
||||||
-- create some simple tables: 1 local and 2 managed by citus
|
-- create some simple tables: 1 local on all nodes and 2 managed by citus
|
||||||
-- d ACL must not be updated in anyway.
|
-- null_privs 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);
|
CREATE TABLE dist_table (id bigint GENERATED BY DEFAULT AS IDENTITY primary key
|
||||||
SELECT create_distributed_table('grant_on_table.dist_table', 'id');
|
, test_a int -- test for INSERT
|
||||||
CREATE TABLE ref_table (id bigint GENERATED BY DEFAULT AS IDENTITY primary key, a int, b text, c int, d text);
|
, test_r text -- test for SELECT
|
||||||
SELECT create_reference_table('grant_on_table.ref_table');
|
, test_w text -- test for UPDATE
|
||||||
|
, test_mix int -- test for ALL/mixed
|
||||||
|
, null_privs text
|
||||||
|
);
|
||||||
|
SELECT create_distributed_table('dist_table', 'id');
|
||||||
|
|
||||||
CREATE TABLE local_table (id int GENERATED BY DEFAULT AS IDENTITY primary key, a int, b text, c int, d text);
|
CREATE TABLE ref_table (id bigint GENERATED BY DEFAULT AS IDENTITY primary key
|
||||||
\c - - - :worker_1_port
|
, test_a int -- test for INSERT
|
||||||
SET search_path TO grant_on_table;
|
, test_r text -- test for SELECT
|
||||||
CREATE TABLE local_table (id int GENERATED BY DEFAULT AS IDENTITY primary key, a int, b text, c int, d text);
|
, test_w text -- test for UPDATE
|
||||||
\c - - - :worker_2_port
|
, test_mix int -- test for ALL
|
||||||
SET search_path TO grant_on_table;
|
, null_privs text
|
||||||
CREATE TABLE local_table (id int GENERATED BY DEFAULT AS IDENTITY primary key, a int, b text, c int, d text);
|
);
|
||||||
\c - - - :master_port
|
SELECT create_reference_table('ref_table');
|
||||||
SET search_path TO grant_on_table;
|
|
||||||
|
SELECT result FROM run_command_on_all_nodes('CREATE TABLE grant_on_table.local_table (id int GENERATED BY DEFAULT AS IDENTITY primary key , test_a int, test_r text, test_w text, test_mix int, null_privs text)');
|
||||||
|
|
||||||
|
-- queries used to check privileges:
|
||||||
|
\set verify_grant_table 'SELECT nodeport, unnest(result::text[]) FROM run_command_on_all_nodes($$SELECT array_agg((relname, relacl) order by 1) FROM pg_class WHERE relname IN (''dist_table'', ''ref_table'', ''local_table'') $$) join pg_dist_node using (nodeid) ORDER BY 2, 1'
|
||||||
|
|
||||||
|
\set verify_grant_attributes 'SELECT nodeport, unnest(coalesce(nullif(result, ''''), ''{}'')::text[]) FROM run_command_on_all_nodes($$SELECT array_agg((attrelid::regclass, attname, attacl) order by 1, 2) FROM pg_attribute WHERE attrelid IN (''grant_on_table.dist_table''::regclass, ''grant_on_table.ref_table''::regclass, ''grant_on_table.local_table''::regclass) AND attacl IS NOT NULL $$) join pg_dist_node using (nodeid) ORDER BY 2, 1'
|
||||||
|
|
||||||
-- create some users
|
-- create some users
|
||||||
CREATE USER grant_user_0;
|
CREATE USER grant_user_0;
|
||||||
|
@ -40,281 +50,392 @@ GRANT USAGE ON SCHEMA grant_on_table TO nogrant_user;
|
||||||
--
|
--
|
||||||
-- tests related to columns ACL
|
-- 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;
|
-- when executing a table level grant, "postgres" is add/listed in pg_class.relacl
|
||||||
-- simple check
|
-- but nothing happens with revoke, as a result pg_class.relacl is not stable.
|
||||||
|
-- in order to have immutable cleanup results in those tests, init the
|
||||||
|
-- "postgres" special case
|
||||||
|
GRANT SELECT ON ref_table TO grant_user_0;
|
||||||
|
REVOKE SELECT ON ref_table FROM grant_user_0;
|
||||||
|
|
||||||
|
--
|
||||||
|
-- check we are able to propagate a single attribute privilege
|
||||||
|
-- we use only SELECT
|
||||||
|
--
|
||||||
SET ROLE grant_user_0;
|
SET ROLE grant_user_0;
|
||||||
-- ok:
|
-- not granted yet:
|
||||||
INSERT INTO grant_on_table.ref_table (a) VALUES (1);
|
SELECT test_r FROM ref_table;
|
||||||
-- not ok:
|
RESET ROLE;
|
||||||
INSERT INTO grant_on_table.ref_table (b) VALUES (1);
|
GRANT SELECT (test_r) ON ref_table TO grant_user_0;
|
||||||
-- ok:
|
SET ROLE grant_user_0;
|
||||||
SELECT a, b, c FROM grant_on_table.ref_table;
|
-- granted:
|
||||||
|
SELECT test_r FROM ref_table;
|
||||||
|
-- not granted:
|
||||||
|
SELECT test_a FROM ref_table;
|
||||||
SET ROLE grant_user_1;
|
SET ROLE grant_user_1;
|
||||||
-- ok:
|
-- not granted:
|
||||||
INSERT INTO grant_on_table.ref_table (a) VALUES (1);
|
SELECT test_r FROM ref_table;
|
||||||
-- 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;
|
RESET ROLE;
|
||||||
|
|
||||||
-- test several tables, several distinct priv, several cols and non cols, several users
|
-- check on coordinator and workers
|
||||||
GRANT UPDATE (c, b), DELETE ON ref_table TO grant_user_0, grant_user_1;
|
:verify_grant_table ;
|
||||||
-- test special case: with system columns (it's ok)
|
:verify_grant_attributes ;
|
||||||
GRANT INSERT (ctid, xmin, b) ON ref_table TO grant_user_0;
|
|
||||||
|
|
||||||
-- simple check
|
-- cleanup
|
||||||
|
REVOKE SELECT (test_r) ON ref_table FROM grant_user_0;
|
||||||
|
|
||||||
|
-- check on coordinator and workers
|
||||||
|
:verify_grant_table ;
|
||||||
|
:verify_grant_attributes ;
|
||||||
|
|
||||||
|
--
|
||||||
|
-- check we are able to propagate a privilege to multiple attributes, users and tables at once
|
||||||
|
-- we use only INSERT/UPDATE
|
||||||
|
--
|
||||||
SET ROLE grant_user_0;
|
SET ROLE grant_user_0;
|
||||||
-- ok:
|
-- not granted yet:
|
||||||
INSERT INTO grant_on_table.ref_table (b) VALUES (1);
|
INSERT INTO ref_table (test_a) VALUES (1);
|
||||||
-- ok:
|
RESET ROLE;
|
||||||
UPDATE grant_on_table.ref_table SET b = 3;
|
-- we would prefer not have to grant INSERT (id) as expected in the standard but
|
||||||
-- not ok:
|
-- Citus rewrite queries with such attributes, which prevent standard to be applied.
|
||||||
UPDATE grant_on_table.ref_table SET d = 3;
|
GRANT INSERT (id, test_a), UPDATE (test_w, test_mix) ON ref_table, dist_table TO grant_user_0, grant_user_1;
|
||||||
DELETE FROM grant_on_table.ref_table;
|
SET ROLE grant_user_0;
|
||||||
|
-- granted:
|
||||||
|
INSERT INTO ref_table (test_a) VALUES (1);
|
||||||
|
-- granted:
|
||||||
|
UPDATE ref_table SET test_w = 2, test_mix = 2;
|
||||||
|
-- not granted:
|
||||||
|
INSERT INTO ref_table (test_w) VALUES (1);
|
||||||
|
SET ROLE grant_user_1;
|
||||||
|
-- granted:
|
||||||
|
INSERT INTO dist_table (test_a) VALUES (1);
|
||||||
|
-- granted:
|
||||||
|
UPDATE dist_table SET test_w = 3, test_mix = 3;
|
||||||
RESET ROLE;
|
RESET ROLE;
|
||||||
|
|
||||||
-- test special case: ALL
|
-- check on coordinator and workers
|
||||||
|
:verify_grant_table ;
|
||||||
|
:verify_grant_attributes ;
|
||||||
|
|
||||||
|
-- cleanup
|
||||||
|
REVOKE INSERT (id, test_a), UPDATE (test_w, test_mix) ON ref_table, dist_table FROM grant_user_0, grant_user_1;
|
||||||
|
|
||||||
|
-- check on coordinator and workers
|
||||||
|
:verify_grant_table ;
|
||||||
|
:verify_grant_attributes ;
|
||||||
|
|
||||||
|
--
|
||||||
|
-- check we are able to propagate a table privilege associated with an attribute level privilege
|
||||||
|
-- we use only SELECT/DELETE
|
||||||
|
--
|
||||||
|
SET ROLE grant_user_0;
|
||||||
|
-- not granted yet:
|
||||||
|
SELECT test_r, test_mix FROM ref_table;
|
||||||
|
RESET ROLE;
|
||||||
|
GRANT SELECT (test_r, test_mix), DELETE ON ref_table TO grant_user_0, grant_user_1;
|
||||||
|
SET ROLE grant_user_0;
|
||||||
|
-- granted:
|
||||||
|
SELECT test_r, test_mix FROM ref_table;
|
||||||
|
-- granted:
|
||||||
|
DELETE FROM ref_table;
|
||||||
|
-- not granted:
|
||||||
|
SELECT test_a FROM ref_table;
|
||||||
|
-- not granted:
|
||||||
|
UPDATE ref_table SET null_privs = 3;
|
||||||
|
RESET ROLE;
|
||||||
|
|
||||||
|
-- check on coordinator and workers
|
||||||
|
:verify_grant_table ;
|
||||||
|
:verify_grant_attributes ;
|
||||||
|
|
||||||
|
-- cleanup
|
||||||
|
REVOKE SELECT (test_r, test_mix), DELETE ON ref_table FROM grant_user_0, grant_user_1;
|
||||||
|
|
||||||
|
-- check on coordinator and workers
|
||||||
|
:verify_grant_table ;
|
||||||
|
:verify_grant_attributes ;
|
||||||
|
|
||||||
|
--
|
||||||
|
-- check we also propagate system columns
|
||||||
|
-- we use only SELECT
|
||||||
|
--
|
||||||
|
SET ROLE grant_user_0;
|
||||||
|
-- not granted yet:
|
||||||
|
SELECT ctid, xmin FROM ref_table;
|
||||||
|
RESET ROLE;
|
||||||
|
GRANT SELECT (ctid, xmin) ON ref_table TO grant_user_0;
|
||||||
|
SET ROLE grant_user_0;
|
||||||
|
-- granted:
|
||||||
|
SELECT ctid, xmin FROM ref_table;
|
||||||
|
-- not granted:
|
||||||
|
SELECT ctid, test_a FROM ref_table;
|
||||||
|
RESET ROLE;
|
||||||
|
|
||||||
|
-- check on coordinator and workers
|
||||||
|
:verify_grant_table ;
|
||||||
|
:verify_grant_attributes ;
|
||||||
|
|
||||||
|
-- cleanup
|
||||||
|
REVOKE SELECT (ctid, xmin) ON ref_table FROM grant_user_0;
|
||||||
|
|
||||||
|
-- check on coordinator and workers
|
||||||
|
:verify_grant_table ;
|
||||||
|
:verify_grant_attributes ;
|
||||||
|
|
||||||
|
--
|
||||||
|
-- check we correctly propagate ALL, which has a few special cases
|
||||||
|
-- we use only ALL/SELECT
|
||||||
|
--
|
||||||
|
SET ROLE grant_user_0;
|
||||||
|
-- not granted yet:
|
||||||
|
INSERT INTO ref_table (id) VALUES (13);
|
||||||
|
SET ROLE grant_user_1;
|
||||||
|
-- not granted yet:
|
||||||
|
INSERT INTO ref_table (id, test_mix) VALUES (9, 3);
|
||||||
|
RESET ROLE;
|
||||||
GRANT ALL (id) ON ref_table TO grant_user_0;
|
GRANT ALL (id) ON ref_table TO grant_user_0;
|
||||||
GRANT ALL (id, c) ON ref_table TO grant_user_1;
|
GRANT ALL (id, test_mix) 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
|
-- ALL cannot be mixed with other privs
|
||||||
GRANT SELECT (d), ALL (d) ON ref_table TO nogrant_user;
|
-- should error:
|
||||||
GRANT ALL (d), SELECT (d) ON ref_table TO nogrant_user;
|
GRANT SELECT (null_privs), ALL (null_privs) ON ref_table TO nogrant_user;
|
||||||
|
-- should error:
|
||||||
-- simple check before the next test
|
GRANT ALL (null_privs), SELECT (null_privs) ON ref_table TO nogrant_user;
|
||||||
|
SET ROLE grant_user_0;
|
||||||
|
-- granted:
|
||||||
|
INSERT INTO ref_table (id) VALUES (13);
|
||||||
SET ROLE grant_user_1;
|
SET ROLE grant_user_1;
|
||||||
-- we've just granted SELECT id on ALL TABLES
|
-- granted:
|
||||||
-- not ok:
|
INSERT INTO ref_table (id, test_mix) VALUES (9, 3);
|
||||||
SELECT id
|
-- not granted:
|
||||||
FROM grant_on_table.ref_table
|
INSERT INTO ref_table (null_privs) VALUES (3);
|
||||||
UNION ALL
|
-- granted:
|
||||||
SELECT id
|
SELECT id, test_mix FROM ref_table;
|
||||||
FROM grant_on_table.dist_table
|
-- not granted:
|
||||||
UNION ALL
|
SELECT null_privs FROM ref_table;
|
||||||
SELECT id
|
-- not granted:
|
||||||
FROM grant_on_table.local_table;
|
DELETE FROM ref_table;
|
||||||
RESET ROLE;
|
RESET ROLE;
|
||||||
|
|
||||||
|
-- check on coordinator and workers
|
||||||
|
:verify_grant_table ;
|
||||||
|
:verify_grant_attributes ;
|
||||||
|
|
||||||
|
-- cleanup
|
||||||
|
REVOKE ALL (id) ON ref_table FROM grant_user_0;
|
||||||
|
REVOKE ALL (id, test_mix) ON ref_table FROM grant_user_1;
|
||||||
|
TRUNCATE ref_table;
|
||||||
|
|
||||||
|
-- check on coordinator and workers
|
||||||
|
:verify_grant_table ;
|
||||||
|
:verify_grant_attributes ;
|
||||||
|
|
||||||
|
--
|
||||||
|
-- check we correctly propagate when mixed with local table, but only on the
|
||||||
|
-- current local table, not others
|
||||||
|
-- we use only INSERT/SELECT
|
||||||
|
--
|
||||||
|
SET ROLE grant_user_0;
|
||||||
|
-- not granted yet:
|
||||||
|
SELECT id FROM ref_table
|
||||||
|
UNION ALL SELECT id FROM dist_table
|
||||||
|
UNION ALL SELECT id FROM local_table;
|
||||||
|
RESET ROLE;
|
||||||
|
-- NOTE:
|
||||||
-- test special case: ALL TABLES IN SCHEMA is not supposed to be correct
|
-- test special case: ALL TABLES IN SCHEMA is not supposed to be correct
|
||||||
-- but is accepted by PostgreSQL - non documented feature
|
-- but is accepted by PostgreSQL - non documented feature
|
||||||
GRANT SELECT (id) ON ALL TABLES IN SCHEMA grant_on_table TO grant_user_1;
|
GRANT SELECT (id) ON ALL TABLES IN SCHEMA grant_on_table TO grant_user_0;
|
||||||
|
-- check non propagation for local table (we'll just check ACL later, no INSERT testing)
|
||||||
-- simple check
|
GRANT INSERT (test_mix) ON local_table TO grant_user_0;
|
||||||
SET ROLE grant_user_1;
|
-- check we can propagate also when mixed with distributed table:
|
||||||
-- we've just granted SELECT id on ALL TABLES
|
GRANT SELECT (test_r, test_mix) ON local_table, dist_table TO grant_user_1;
|
||||||
-- 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;
|
SET ROLE grant_user_0;
|
||||||
-- not ok:
|
-- granted:
|
||||||
SELECT a FROM grant_on_table.ref_table;
|
SELECT id FROM ref_table
|
||||||
RESET ROLE;
|
UNION ALL SELECT id FROM dist_table
|
||||||
REVOKE ALL(id, b) ON ref_table, dist_table, local_table from grant_user_0, grant_user_1;
|
UNION ALL SELECT id FROM local_table;
|
||||||
-- simple check
|
SET ROLE grant_user_1;
|
||||||
SET ROLE grant_user_0;
|
-- granted:
|
||||||
-- not ok:
|
SELECT test_r, test_mix FROM dist_table
|
||||||
SELECT b FROM grant_on_table.ref_table;
|
UNION ALL SELECT test_r, test_mix FROM local_table;
|
||||||
RESET ROLE;
|
RESET ROLE;
|
||||||
|
|
||||||
-- check on coordinator and workers
|
-- check on coordinator and workers
|
||||||
SELECT relname, relacl FROM pg_class
|
-- we pay special attention to local_table privileges here:
|
||||||
WHERE relname IN ('dist_table', 'ref_table', 'local_table') ORDER BY 1;
|
:verify_grant_table ;
|
||||||
SELECT attrelid::regclass, attname, attacl FROM pg_attribute
|
:verify_grant_attributes ;
|
||||||
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
|
-- cleanup
|
||||||
REVOKE ALL ON ref_table, dist_table, local_table from grant_user_0, grant_user_1;
|
REVOKE SELECT (id) ON ALL TABLES IN SCHEMA grant_on_table FROM grant_user_0;
|
||||||
-- and try some WITH GRANT OPTION
|
-- check non propagation for local table (we'll just check ACL later, no INSERT testing)
|
||||||
GRANT ALL(id, b) ON ref_table TO grant_user_0 WITH GRANT OPTION;
|
REVOKE INSERT (test_mix) ON local_table FROM grant_user_0;
|
||||||
|
-- check we can propagate also when mixed with distributed table:
|
||||||
|
REVOKE SELECT (test_r, test_mix) ON local_table, dist_table FROM grant_user_1;
|
||||||
|
|
||||||
|
-- check on coordinator and workers
|
||||||
|
:verify_grant_table ;
|
||||||
|
:verify_grant_attributes ;
|
||||||
|
|
||||||
|
--
|
||||||
|
-- check TRUNCATE is not propagated (inccorect grammar)
|
||||||
|
-- also ensure no privs are propagated at all with "partially" incorrect grammar
|
||||||
|
-- we use only TRUNCATE/SELECT
|
||||||
|
--
|
||||||
SET ROLE grant_user_0;
|
SET ROLE grant_user_0;
|
||||||
GRANT ALL(id, b) ON grant_on_table.ref_table TO grant_user_1;
|
-- not granted yet:
|
||||||
SET ROLE grant_user_1;
|
SELECT test_r FROM ref_table;
|
||||||
INSERT INTO grant_on_table.ref_table (b) VALUES ('OK');
|
RESET ROLE;
|
||||||
SELECT id, b FROM grant_on_table.ref_table;
|
GRANT TRUNCATE (null_privs), SELECT (null_privs) ON ref_table TO nogrant_user;
|
||||||
|
SET ROLE grant_user_0;
|
||||||
|
-- still not granted:
|
||||||
|
SELECT test_r FROM ref_table;
|
||||||
|
-- still not granted:
|
||||||
|
TRUNCATE ref_table;
|
||||||
RESET ROLE;
|
RESET ROLE;
|
||||||
|
|
||||||
-- cleanup
|
-- check on coordinator and workers
|
||||||
|
:verify_grant_table ;
|
||||||
|
:verify_grant_attributes ;
|
||||||
|
|
||||||
|
-- no cleanup required
|
||||||
|
|
||||||
|
--
|
||||||
|
-- check we do not propage from a worker
|
||||||
|
-- we use only SELECT
|
||||||
|
--
|
||||||
|
\c - - - :worker_1_port
|
||||||
|
SET search_path TO grant_on_table;
|
||||||
|
GRANT SELECT (test_r, test_mix) ON ref_table TO grant_user_0;
|
||||||
|
\c - - - :master_port
|
||||||
|
SET search_path TO grant_on_table;
|
||||||
|
|
||||||
|
-- check on coordinator and workers
|
||||||
|
:verify_grant_table ;
|
||||||
|
:verify_grant_attributes ;
|
||||||
|
|
||||||
|
-- no cleanup required
|
||||||
|
|
||||||
|
--
|
||||||
|
-- check we do propagate WITH GRANT OPTION
|
||||||
|
-- we use only SELECT
|
||||||
|
--
|
||||||
|
SET ROLE grant_user_0;
|
||||||
|
-- not granted yet:
|
||||||
|
SELECT test_r, test_mix FROM ref_table;
|
||||||
|
SET ROLE grant_user_1;
|
||||||
|
-- not granted yet:
|
||||||
|
SELECT test_r, test_mix FROM ref_table;
|
||||||
|
RESET ROLE;
|
||||||
|
-- grant with grant option
|
||||||
|
GRANT SELECT (test_r, test_mix) ON ref_table TO grant_user_0 WITH GRANT OPTION;
|
||||||
|
SET ROLE grant_user_0;
|
||||||
|
-- grant using a role with grant option
|
||||||
|
GRANT SELECT (test_r, test_mix) ON ref_table TO grant_user_1;
|
||||||
|
SET ROLE grant_user_1;
|
||||||
|
-- granted:
|
||||||
|
SELECT test_r, test_mix FROM ref_table;
|
||||||
|
RESET ROLE;
|
||||||
|
|
||||||
|
-- check on coordinator and workers
|
||||||
|
:verify_grant_table ;
|
||||||
|
:verify_grant_attributes ;
|
||||||
|
|
||||||
|
-- cleanup and further checks:
|
||||||
|
SET ROLE grant_user_0;
|
||||||
|
-- revoke as grant_user_0:
|
||||||
|
REVOKE SELECT (test_r, test_mix) ON ref_table FROM grant_user_1;
|
||||||
|
RESET ROLE;
|
||||||
|
-- check on coordinator and workers
|
||||||
|
:verify_grant_table ;
|
||||||
|
:verify_grant_attributes ;
|
||||||
|
|
||||||
|
-- revoke only grant options from grant_user_0:
|
||||||
|
REVOKE GRANT OPTION FOR SELECT (test_r, test_mix) ON ref_table FROM grant_user_0;
|
||||||
|
-- check on coordinator and workers
|
||||||
|
:verify_grant_table ;
|
||||||
|
:verify_grant_attributes ;
|
||||||
|
|
||||||
|
-- revoke select from grant_user_0:
|
||||||
|
REVOKE SELECT (test_r, test_mix) ON ref_table FROM grant_user_0;
|
||||||
|
-- check on coordinator and workers
|
||||||
|
:verify_grant_table ;
|
||||||
|
:verify_grant_attributes ;
|
||||||
|
|
||||||
-- prevent useless messages on DROP objects.
|
-- prevent useless messages on DROP objects.
|
||||||
SET client_min_messages TO ERROR;
|
SET client_min_messages TO ERROR;
|
||||||
DROP SCHEMA grant_on_table CASCADE;
|
DROP TABLE dist_table, ref_table;
|
||||||
DROP ROLE grant_user_0, grant_user_1, nogrant_user;
|
SELECT result FROM run_command_on_all_nodes('DROP TABLE grant_on_table.local_table');
|
||||||
RESET client_min_messages;
|
RESET client_min_messages;
|
||||||
RESET search_path;
|
|
||||||
|
|
||||||
-- test propagation on columns when adding a node after GRANT has been executed
|
--
|
||||||
CREATE SCHEMA grant_on_table;
|
-- check we propagate privileges when GRANTed before distributed and when adding a node
|
||||||
SET search_path TO grant_on_table;
|
-- we use only SELECT
|
||||||
|
--
|
||||||
CREATE ROLE grant_role_propagated;
|
-- test propagation on columns when distributing the table after GRANT has been executed
|
||||||
CREATE TABLE grant_table_propagated (id int primary key);
|
CREATE TABLE grant_table_propagated (id int primary key);
|
||||||
GRANT ALL(id) ON grant_table_propagated TO grant_role_propagated;
|
GRANT SELECT (id) ON grant_table_propagated TO grant_user_0;
|
||||||
SELECT create_distributed_table('grant_table_propagated', 'id');
|
SELECT create_distributed_table('grant_table_propagated', 'id');
|
||||||
|
SET ROLE grant_user_0;
|
||||||
|
-- granted:
|
||||||
|
SELECT id FROM grant_table_propagated;
|
||||||
|
RESET ROLE;
|
||||||
|
|
||||||
SELECT '$$SELECT array_agg((attname, attacl) order by attname) FROM pg_attribute
|
-- check on coordinator and workers
|
||||||
WHERE attrelid = ''grant_on_table.grant_table_propagated''::regclass
|
\set verify_grant_table 'SELECT nodeport, unnest(result::text[]) FROM run_command_on_all_nodes($$SELECT array_agg((relname, relacl) order by 1) FROM pg_class WHERE relname IN (''grant_table_propagated'') $$) join pg_dist_node using (nodeid) ORDER BY 2, 1'
|
||||||
AND attacl IS NOT NULL$$' AS verify_grant_query \gset
|
|
||||||
|
|
||||||
SELECT result FROM run_command_on_all_nodes(:verify_grant_query);
|
\set verify_grant_attributes 'SELECT nodeport, unnest(coalesce(nullif(result, ''''), ''{}'')::text[]) FROM run_command_on_all_nodes($$SELECT array_agg((attrelid::regclass, attname, attacl) order by 1, 2) FROM pg_attribute WHERE attrelid IN (''grant_on_table.grant_table_propagated''::regclass) AND attacl IS NOT NULL $$) join pg_dist_node using (nodeid) ORDER BY 2, 1'
|
||||||
|
|
||||||
|
:verify_grant_table ;
|
||||||
|
:verify_grant_attributes ;
|
||||||
|
|
||||||
-- cleanup
|
-- cleanup
|
||||||
|
REVOKE SELECT (id) ON grant_table_propagated FROM grant_user_0;
|
||||||
|
|
||||||
|
:verify_grant_table ;
|
||||||
|
:verify_grant_attributes ;
|
||||||
|
|
||||||
-- prevent useless messages on DROP objects.
|
-- prevent useless messages on DROP objects.
|
||||||
SET client_min_messages TO ERROR;
|
SET client_min_messages TO ERROR;
|
||||||
DROP TABLE grant_table_propagated;
|
DROP TABLE grant_table_propagated;
|
||||||
DROP ROLE grant_role_propagated;
|
|
||||||
RESET client_min_messages;
|
RESET client_min_messages;
|
||||||
|
|
||||||
-- similar test but just adding a node after the fact
|
-- similar test but adding a node after the fact
|
||||||
-- remove one of the worker nodes:
|
-- remove one of the worker nodes:
|
||||||
SELECT citus_remove_node('localhost', :worker_2_port);
|
SELECT citus_remove_node('localhost', :worker_2_port);
|
||||||
|
|
||||||
CREATE ROLE grant_role_propagated_after;
|
|
||||||
CREATE TABLE grant_table_propagated_after (id int primary key);
|
CREATE TABLE grant_table_propagated_after (id int primary key);
|
||||||
SET citus.shard_replication_factor TO 1;
|
SET citus.shard_replication_factor TO 1;
|
||||||
SELECT create_distributed_table('grant_on_table.grant_table_propagated_after', 'id');
|
SELECT create_distributed_table('grant_table_propagated_after', 'id');
|
||||||
SET citus.shard_replication_factor TO 2;
|
SET citus.shard_replication_factor TO 2;
|
||||||
GRANT ALL(id) ON grant_table_propagated_after TO grant_role_propagated_after;
|
GRANT SELECT (id) ON grant_table_propagated_after TO grant_user_0;
|
||||||
|
|
||||||
-- add back the worker node
|
-- add back the worker node
|
||||||
SELECT FROM citus_add_node('localhost', :worker_2_port);
|
SELECT FROM citus_add_node('localhost', :worker_2_port);
|
||||||
|
|
||||||
SELECT '$$SELECT array_agg((attname, attacl) order by attname) FROM pg_attribute
|
-- granted:
|
||||||
WHERE attrelid = ''grant_on_table.grant_table_propagated_after''::regclass
|
SELECT id FROM grant_table_propagated_after;
|
||||||
AND attacl IS NOT NULL$$' AS verify_grant_query \gset
|
|
||||||
|
|
||||||
SELECT result FROM run_command_on_all_nodes(:verify_grant_query);
|
-- check on coordinator and workers
|
||||||
|
\set verify_grant_table 'SELECT nodeport, unnest(result::text[]) FROM run_command_on_all_nodes($$SELECT array_agg((relname, relacl) order by 1) FROM pg_class WHERE relname IN (''grant_table_propagated_after'') $$) join pg_dist_node using (nodeid) ORDER BY 2, 1'
|
||||||
|
|
||||||
|
\set verify_grant_attributes 'SELECT nodeport, unnest(coalesce(nullif(result, ''''), ''{}'')::text[]) FROM run_command_on_all_nodes($$SELECT array_agg((attrelid::regclass, attname, attacl) order by 1, 2) FROM pg_attribute WHERE attrelid IN (''grant_on_table.grant_table_propagated_after''::regclass) AND attacl IS NOT NULL $$) join pg_dist_node using (nodeid) ORDER BY 2, 1'
|
||||||
|
|
||||||
|
:verify_grant_table ;
|
||||||
|
:verify_grant_attributes ;
|
||||||
|
|
||||||
-- cleanup
|
-- cleanup
|
||||||
|
REVOKE SELECT (id) ON grant_table_propagated_after FROM grant_user_0;
|
||||||
|
|
||||||
|
:verify_grant_table ;
|
||||||
|
:verify_grant_attributes ;
|
||||||
|
|
||||||
|
-- prevent useless messages on DROP objects.
|
||||||
|
SET client_min_messages TO ERROR;
|
||||||
|
DROP TABLE grant_table_propagated_after;
|
||||||
|
RESET client_min_messages;
|
||||||
|
|
||||||
|
-- global cleanup
|
||||||
-- prevent useless messages on DROP objects.
|
-- prevent useless messages on DROP objects.
|
||||||
SET client_min_messages TO ERROR;
|
SET client_min_messages TO ERROR;
|
||||||
DROP SCHEMA grant_on_table CASCADE;
|
DROP SCHEMA grant_on_table CASCADE;
|
||||||
DROP ROLE grant_role_propagated_after;
|
DROP ROLE grant_user_0, grant_user_1;
|
||||||
RESET client_min_messages;
|
RESET client_min_messages;
|
||||||
RESET search_path;
|
RESET search_path;
|
||||||
|
|
Loading…
Reference in New Issue