From b40f067d05fc03e08b2f6999396f928dbc2bdb41 Mon Sep 17 00:00:00 2001 From: Halil Ozan Akgul Date: Wed, 15 Jan 2020 11:51:52 +0300 Subject: [PATCH] Adds propagation for grant on schema commands --- .../distributed/commands/dependencies.c | 10 +- .../commands/distribute_object_ops.c | 21 +- src/backend/distributed/commands/schema.c | 73 ++++ .../deparser/deparse_schema_stmts.c | 133 +++++++ .../distributed/metadata/metadata_sync.c | 122 ++++++ src/include/distributed/commands.h | 1 + src/include/distributed/deparser.h | 3 + src/include/distributed/metadata_sync.h | 1 + .../expected/grant_on_schema_propagation.out | 364 ++++++++++++++++++ src/test/regress/multi_schedule | 2 + .../sql/grant_on_schema_propagation.sql | 177 +++++++++ 11 files changed, 904 insertions(+), 3 deletions(-) create mode 100644 src/backend/distributed/deparser/deparse_schema_stmts.c create mode 100644 src/test/regress/expected/grant_on_schema_propagation.out create mode 100644 src/test/regress/sql/grant_on_schema_propagation.sql diff --git a/src/backend/distributed/commands/dependencies.c b/src/backend/distributed/commands/dependencies.c index b0aab9ae4..c65f2a3c8 100644 --- a/src/backend/distributed/commands/dependencies.c +++ b/src/backend/distributed/commands/dependencies.c @@ -171,7 +171,7 @@ GetDependencyCreateDDLCommands(const ObjectAddress *dependency) case OCLASS_SCHEMA: { - const char *schemaDDLCommand = CreateSchemaDDLCommand(dependency->objectId); + char *schemaDDLCommand = CreateSchemaDDLCommand(dependency->objectId); if (schemaDDLCommand == NULL) { @@ -179,7 +179,13 @@ GetDependencyCreateDDLCommands(const ObjectAddress *dependency) return NIL; } - return list_make1((void *) schemaDDLCommand); + List *DDLCommands = list_make1(schemaDDLCommand); + + List *grantDDLCommands = GrantOnSchemaDDLCommands(dependency->objectId); + + DDLCommands = list_concat(DDLCommands, grantDDLCommands); + + return DDLCommands; } case OCLASS_TYPE: diff --git a/src/backend/distributed/commands/distribute_object_ops.c b/src/backend/distributed/commands/distribute_object_ops.c index 157393235..fb15fa622 100644 --- a/src/backend/distributed/commands/distribute_object_ops.c +++ b/src/backend/distributed/commands/distribute_object_ops.c @@ -372,6 +372,13 @@ static DistributeObjectOps Schema_Drop = { .postprocess = NULL, .address = NULL, }; +static DistributeObjectOps Schema_Grant = { + .deparse = DeparseGrantOnSchemaStmt, + .qualify = NULL, + .preprocess = PreprocessGrantOnSchemaStmt, + .postprocess = NULL, + .address = NULL, +}; static DistributeObjectOps Table_AlterTable = { .deparse = NULL, .qualify = NULL, @@ -749,7 +756,19 @@ GetDistributeObjectOps(Node *node) case T_GrantStmt: { - return &Any_Grant; + GrantStmt *stmt = castNode(GrantStmt, node); + switch (stmt->objtype) + { + case OBJECT_SCHEMA: + { + return &Schema_Grant; + } + + default: + { + return &Any_Grant; + } + } } case T_IndexStmt: diff --git a/src/backend/distributed/commands/schema.c b/src/backend/distributed/commands/schema.c index da67cc6b6..92cc79698 100644 --- a/src/backend/distributed/commands/schema.c +++ b/src/backend/distributed/commands/schema.c @@ -17,9 +17,12 @@ #include "access/htup_details.h" #include "catalog/namespace.h" #include "catalog/pg_class.h" +#include "catalog/pg_namespace.h" #include "distributed/commands.h" #include #include "distributed/commands/utility_hook.h" +#include "distributed/deparser.h" +#include "distributed/metadata/distobject.h" #include "distributed/metadata_cache.h" #include #include @@ -30,6 +33,9 @@ #include "utils/relcache.h" +static List * FilterDistributedSchemas(List *schemas); + + /* * PreprocessDropSchemaStmt invalidates the foreign key cache if any table created * under dropped schema involved in any foreign key relationship. @@ -104,3 +110,70 @@ PreprocessDropSchemaStmt(Node *node, const char *queryString) return NIL; } + + +/* + * PreprocessGrantOnSchemaStmt is executed before the statement is applied to the local + * postgres instance. + * + * In this stage we can prepare the commands that need to be run on all workers to grant + * on schemas. Only grant statements for distributed schema are propagated. + */ +List * +PreprocessGrantOnSchemaStmt(Node *node, const char *queryString) +{ + GrantStmt *stmt = castNode(GrantStmt, node); + Assert(stmt->objtype == OBJECT_SCHEMA); + + List *distributedSchemas = FilterDistributedSchemas(stmt->objects); + + if (list_length(distributedSchemas) == 0) + { + return NIL; + } + + List *originalObjects = stmt->objects; + + stmt->objects = distributedSchemas; + + char *sql = DeparseTreeNode((Node *) stmt); + + stmt->objects = originalObjects; + + return NodeDDLTaskList(ALL_WORKERS, list_make1(sql)); +} + + +/* + * FilterDistributedSchemas filters the schema list and returns the distributed ones + * as a list + */ +static List * +FilterDistributedSchemas(List *schemas) +{ + List *distributedSchemas = NIL; + ListCell *cell = NULL; + + foreach(cell, schemas) + { + char *schemaName = strVal(lfirst(cell)); + Oid schemaOid = get_namespace_oid(schemaName, true); + + if (!OidIsValid(schemaOid)) + { + continue; + } + + ObjectAddress address = { 0 }; + ObjectAddressSet(address, NamespaceRelationId, schemaOid); + + if (!IsObjectDistributed(&address)) + { + continue; + } + + distributedSchemas = lappend(distributedSchemas, makeString(schemaName)); + } + + return distributedSchemas; +} diff --git a/src/backend/distributed/deparser/deparse_schema_stmts.c b/src/backend/distributed/deparser/deparse_schema_stmts.c new file mode 100644 index 000000000..2aa4a6439 --- /dev/null +++ b/src/backend/distributed/deparser/deparse_schema_stmts.c @@ -0,0 +1,133 @@ +/*------------------------------------------------------------------------- + * + * deparse_schema_stmts.c + * All routines to deparse schema statements. + * This file contains all entry points specific for type statement deparsing as well as + * functions that are currently only used for deparsing of the schema statements. + * + * Copyright (c) Citus Data, Inc. + * + *------------------------------------------------------------------------- + */ +#include "postgres.h" + +#include "distributed/citus_ruleutils.h" +#include "distributed/deparser.h" +#include "lib/stringinfo.h" +#include "nodes/nodes.h" +#include "utils/builtins.h" + +static void AppendGrantOnSchemaStmt(StringInfo buf, GrantStmt *stmt); +static void AppendGrantOnSchemaPrivileges(StringInfo buf, GrantStmt *stmt); +static void AppendGrantOnSchemaSchemas(StringInfo buf, GrantStmt *stmt); +static void AppendGrantOnSchemaGrantees(StringInfo buf, GrantStmt *stmt); + +char * +DeparseGrantOnSchemaStmt(Node *node) +{ + GrantStmt *stmt = castNode(GrantStmt, node); + Assert(stmt->objtype == OBJECT_SCHEMA); + + StringInfoData str = { 0 }; + initStringInfo(&str); + + AppendGrantOnSchemaStmt(&str, stmt); + + return str.data; +} + + +static void +AppendGrantOnSchemaStmt(StringInfo buf, GrantStmt *stmt) +{ + Assert(stmt->objtype == OBJECT_SCHEMA); + + appendStringInfo(buf, "%s ", stmt->is_grant ? "GRANT" : "REVOKE"); + + if (!stmt->is_grant && stmt->grant_option) + { + appendStringInfo(buf, "GRANT OPTION FOR "); + } + + AppendGrantOnSchemaPrivileges(buf, stmt); + + AppendGrantOnSchemaSchemas(buf, stmt); + + AppendGrantOnSchemaGrantees(buf, stmt); + + if (stmt->is_grant && stmt->grant_option) + { + appendStringInfo(buf, " WITH GRANT OPTION"); + } + if (!stmt->is_grant) + { + if (stmt->behavior == DROP_RESTRICT) + { + appendStringInfo(buf, " RESTRICT"); + } + else if (stmt->behavior == DROP_CASCADE) + { + appendStringInfo(buf, " CASCADE"); + } + } + appendStringInfo(buf, ";"); +} + + +static void +AppendGrantOnSchemaPrivileges(StringInfo buf, GrantStmt *stmt) +{ + if (list_length(stmt->privileges) == 0) + { + appendStringInfo(buf, "ALL PRIVILEGES"); + } + else + { + ListCell *cell = NULL; + foreach(cell, stmt->privileges) + { + AccessPriv *privilege = (AccessPriv *) lfirst(cell); + appendStringInfoString(buf, privilege->priv_name); + if (cell != list_tail(stmt->privileges)) + { + appendStringInfo(buf, ", "); + } + } + } +} + + +static void +AppendGrantOnSchemaSchemas(StringInfo buf, GrantStmt *stmt) +{ + ListCell *cell = NULL; + appendStringInfo(buf, " ON SCHEMA "); + + foreach(cell, stmt->objects) + { + char *schema = strVal(lfirst(cell)); + appendStringInfoString(buf, quote_identifier(schema)); + if (cell != list_tail(stmt->objects)) + { + appendStringInfo(buf, ", "); + } + } +} + + +static void +AppendGrantOnSchemaGrantees(StringInfo buf, GrantStmt *stmt) +{ + ListCell *cell = NULL; + appendStringInfo(buf, " %s ", stmt->is_grant ? "TO" : "FROM"); + + foreach(cell, stmt->grantees) + { + RoleSpec *grantee = (RoleSpec *) lfirst(cell); + appendStringInfoString(buf, RoleSpecString(grantee, true)); + if (cell != list_tail(stmt->grantees)) + { + appendStringInfo(buf, ", "); + } + } +} diff --git a/src/backend/distributed/metadata/metadata_sync.c b/src/backend/distributed/metadata/metadata_sync.c index c016cfacb..acff0f6ed 100644 --- a/src/backend/distributed/metadata/metadata_sync.c +++ b/src/backend/distributed/metadata/metadata_sync.c @@ -29,6 +29,7 @@ #include "catalog/pg_type.h" #include "distributed/citus_ruleutils.h" #include "distributed/commands.h" +#include "distributed/deparser.h" #include "distributed/distribution_column.h" #include "distributed/listutils.h" #include "distributed/master_metadata_utility.h" @@ -43,6 +44,7 @@ #include "distributed/worker_transaction.h" #include "distributed/version_compat.h" #include "foreign/foreign.h" +#include "miscadmin.h" #include "nodes/pg_list.h" #include "storage/lmgr.h" #include "utils/builtins.h" @@ -61,6 +63,13 @@ static char * SchemaOwnerName(Oid objectId); static bool HasMetadataWorkers(void); static List * DetachPartitionCommandList(void); static bool SyncMetadataSnapshotToNode(WorkerNode *workerNode, bool raiseOnError); +static List * GenerateGrantOnSchemaQueriesFromAclItem(Oid schemaOid, + AclItem *aclItem); +static GrantStmt * GenerateGrantOnSchemaStmtForRights(Oid roleOid, + Oid schemaOid, + char *permission, + bool withGrantOption); +static char * GenerateSetRoleQuery(Oid roleOid); PG_FUNCTION_INFO_V1(start_metadata_sync_to_node); PG_FUNCTION_INFO_V1(stop_metadata_sync_to_node); @@ -1106,6 +1115,119 @@ CreateSchemaDDLCommand(Oid schemaId) } +/* + * GrantOnSchemaDDLCommands creates a list of ddl command for replicating the permissions + * of roles on schemas. + */ +List * +GrantOnSchemaDDLCommands(Oid schemaOid) +{ + HeapTuple schemaTuple = SearchSysCache1(NAMESPACEOID, ObjectIdGetDatum(schemaOid)); + bool isNull = true; + Datum aclDatum = SysCacheGetAttr(NAMESPACEOID, schemaTuple, Anum_pg_namespace_nspacl, + &isNull); + if (isNull) + { + ReleaseSysCache(schemaTuple); + return NIL; + } + Acl *acl = DatumGetAclPCopy(aclDatum); + AclItem *aclDat = ACL_DAT(acl); + int aclNum = ACL_NUM(acl); + List *commands = NIL; + + ReleaseSysCache(schemaTuple); + + for (int i = 0; i < aclNum; i++) + { + commands = list_concat(commands, + GenerateGrantOnSchemaQueriesFromAclItem( + schemaOid, + &aclDat[i])); + } + + return commands; +} + + +/* + * GenerateGrantOnSchemaQueryFromACL generates a query string for replicating a users permissions + * on a schema. + */ +List * +GenerateGrantOnSchemaQueriesFromAclItem(Oid schemaOid, AclItem *aclItem) +{ + AclMode permissions = ACLITEM_GET_PRIVS(*aclItem) & ACL_ALL_RIGHTS_SCHEMA; + AclMode grants = ACLITEM_GET_GOPTIONS(*aclItem) & ACL_ALL_RIGHTS_SCHEMA; + + /* + * seems unlikely but we check if there is a grant option in the list without the actual permission + */ + Assert(!(grants & ACL_USAGE) || (permissions & ACL_USAGE)); + Assert(!(grants & ACL_CREATE) || (permissions & ACL_CREATE)); + Oid granteeOid = aclItem->ai_grantee; + List *queries = NIL; + + queries = lappend(queries, GenerateSetRoleQuery(aclItem->ai_grantor)); + + if (permissions & ACL_USAGE) + { + char *query = DeparseTreeNode((Node *) GenerateGrantOnSchemaStmtForRights( + granteeOid, schemaOid, "USAGE", grants & + ACL_USAGE)); + queries = lappend(queries, query); + } + if (permissions & ACL_CREATE) + { + char *query = DeparseTreeNode((Node *) GenerateGrantOnSchemaStmtForRights( + granteeOid, schemaOid, "CREATE", grants & + ACL_CREATE)); + queries = lappend(queries, query); + } + + queries = lappend(queries, "RESET ROLE"); + + return queries; +} + + +GrantStmt * +GenerateGrantOnSchemaStmtForRights(Oid roleOid, + Oid schemaOid, + char *permission, + bool withGrantOption) +{ + AccessPriv *accessPriv = makeNode(AccessPriv); + accessPriv->priv_name = permission; + accessPriv->cols = NULL; + + RoleSpec *roleSpec = makeNode(RoleSpec); + roleSpec->roletype = OidIsValid(roleOid) ? ROLESPEC_CSTRING : ROLESPEC_PUBLIC; + roleSpec->rolename = OidIsValid(roleOid) ? GetUserNameFromId(roleOid, false) : NULL; + roleSpec->location = -1; + + GrantStmt *stmt = makeNode(GrantStmt); + stmt->is_grant = true; + stmt->targtype = ACL_TARGET_OBJECT; + stmt->objtype = OBJECT_SCHEMA; + stmt->objects = list_make1(makeString(get_namespace_name(schemaOid))); + stmt->privileges = list_make1(accessPriv); + stmt->grantees = list_make1(roleSpec); + stmt->grant_option = withGrantOption; + return stmt; +} + + +static char * +GenerateSetRoleQuery(Oid roleOid) +{ + StringInfo buf = makeStringInfo(); + appendStringInfo(buf, "SET ROLE %s", quote_identifier(GetUserNameFromId(roleOid, + false))); + return buf->data; +} + + /* * TruncateTriggerCreateCommand creates a SQL query calling worker_create_truncate_trigger * function, which creates the truncate trigger on the worker. diff --git a/src/include/distributed/commands.h b/src/include/distributed/commands.h index 032e92db5..cadc282c6 100644 --- a/src/include/distributed/commands.h +++ b/src/include/distributed/commands.h @@ -190,6 +190,7 @@ extern List * PreprocessDropSchemaStmt(Node *dropSchemaStatement, const char *queryString); extern List * PreprocessAlterObjectSchemaStmt(Node *alterObjectSchemaStmt, const char *alterObjectSchemaCommand); +extern List * PreprocessGrantOnSchemaStmt(Node *node, const char *queryString); /* sequence.c - forward declarations */ diff --git a/src/include/distributed/deparser.h b/src/include/distributed/deparser.h index 3b1a5c04c..c016665b0 100644 --- a/src/include/distributed/deparser.h +++ b/src/include/distributed/deparser.h @@ -51,6 +51,9 @@ extern char * DeparseAlterTableSchemaStmt(Node *stmt); extern void QualifyAlterTableSchemaStmt(Node *stmt); +/* forward declarations for deparse_schema_stmts.c */ +extern char * DeparseGrantOnSchemaStmt(Node *stmt); + /* forward declarations for deparse_type_stmts.c */ extern char * DeparseCompositeTypeStmt(Node *stmt); extern char * DeparseCreateEnumStmt(Node *stmt); diff --git a/src/include/distributed/metadata_sync.h b/src/include/distributed/metadata_sync.h index 9e00df41a..a69c1a62c 100644 --- a/src/include/distributed/metadata_sync.h +++ b/src/include/distributed/metadata_sync.h @@ -46,6 +46,7 @@ extern char * NodeStateUpdateCommand(uint32 nodeId, bool isActive); extern char * ShouldHaveShardsUpdateCommand(uint32 nodeId, bool shouldHaveShards); extern char * ColocationIdUpdateCommand(Oid relationId, uint32 colocationId); extern char * CreateSchemaDDLCommand(Oid schemaId); +extern List * GrantOnSchemaDDLCommands(Oid schemaId); extern char * PlacementUpsertCommand(uint64 shardId, uint64 placementId, int shardState, uint64 shardLength, int32 groupId); extern void CreateTableMetadataOnWorkers(Oid relationId); diff --git a/src/test/regress/expected/grant_on_schema_propagation.out b/src/test/regress/expected/grant_on_schema_propagation.out new file mode 100644 index 000000000..58266e44a --- /dev/null +++ b/src/test/regress/expected/grant_on_schema_propagation.out @@ -0,0 +1,364 @@ +-- +-- GRANT_ON_SCHEMA_PROPAGATION +-- +-- test grants are propagated when the schema is +CREATE SCHEMA dist_schema; +CREATE TABLE dist_schema.dist_table (id int); +CREATE SCHEMA another_dist_schema; +CREATE TABLE another_dist_schema.dist_table (id int); +CREATE SCHEMA non_dist_schema; +-- create roles on all nodes +SELECT run_command_on_coordinator_and_workers('CREATE USER role_1'); +NOTICE: not propagating CREATE ROLE/USER commands to worker nodes +HINT: Connect to worker nodes directly to manually create all necessary users and roles. +CONTEXT: SQL statement "CREATE USER role_1" +PL/pgSQL function run_command_on_coordinator_and_workers(text) line 3 at EXECUTE + run_command_on_coordinator_and_workers +--------------------------------------------------------------------- + +(1 row) + +SELECT run_command_on_coordinator_and_workers('CREATE USER role_2'); +NOTICE: not propagating CREATE ROLE/USER commands to worker nodes +HINT: Connect to worker nodes directly to manually create all necessary users and roles. +CONTEXT: SQL statement "CREATE USER role_2" +PL/pgSQL function run_command_on_coordinator_and_workers(text) line 3 at EXECUTE + run_command_on_coordinator_and_workers +--------------------------------------------------------------------- + +(1 row) + +SELECT run_command_on_coordinator_and_workers('CREATE USER role_3'); +NOTICE: not propagating CREATE ROLE/USER commands to worker nodes +HINT: Connect to worker nodes directly to manually create all necessary users and roles. +CONTEXT: SQL statement "CREATE USER role_3" +PL/pgSQL function run_command_on_coordinator_and_workers(text) line 3 at EXECUTE + run_command_on_coordinator_and_workers +--------------------------------------------------------------------- + +(1 row) + +-- do some varying grants +GRANT USAGE, CREATE ON SCHEMA dist_schema TO role_1 WITH GRANT OPTION; +GRANT USAGE ON SCHEMA dist_schema TO role_2; +SET ROLE role_1; +GRANT USAGE ON SCHEMA dist_schema TO role_3 WITH GRANT OPTION; +GRANT CREATE ON SCHEMA dist_schema TO role_3; +GRANT CREATE, USAGE ON SCHEMA dist_schema TO PUBLIC; +RESET ROLE; +GRANT USAGE ON SCHEMA dist_schema TO PUBLIC; +SELECT create_distributed_table('dist_schema.dist_table', 'id'); + create_distributed_table +--------------------------------------------------------------------- + +(1 row) + +SELECT create_distributed_table('another_dist_schema.dist_table', 'id'); + create_distributed_table +--------------------------------------------------------------------- + +(1 row) + +SELECT nspname, nspacl FROM pg_namespace WHERE nspname = 'dist_schema'; + nspname | nspacl +--------------------------------------------------------------------- + dist_schema | {postgres=UC/postgres,role_1=U*C*/postgres,role_2=U/postgres,role_3=U*C/role_1,=UC/role_1,=U/postgres} +(1 row) + +\c - - - :worker_1_port +SELECT nspname, nspacl FROM pg_namespace WHERE nspname = 'dist_schema'; + nspname | nspacl +--------------------------------------------------------------------- + dist_schema | {postgres=UC/postgres,role_1=U*C*/postgres,role_2=U/postgres,role_3=U*C/role_1,=UC/role_1,=U/postgres} +(1 row) + +\c - - - :master_port +-- grant all permissions +GRANT ALL ON SCHEMA dist_schema, another_dist_schema, non_dist_schema TO role_1, role_2, role_3 WITH GRANT OPTION; +SELECT nspname, nspacl FROM pg_namespace WHERE nspname IN ('dist_schema', 'another_dist_schema', 'non_dist_schema') ORDER BY nspname; + nspname | nspacl +--------------------------------------------------------------------- + another_dist_schema | {postgres=UC/postgres,role_1=U*C*/postgres,role_2=U*C*/postgres,role_3=U*C*/postgres} + dist_schema | {postgres=UC/postgres,role_1=U*C*/postgres,role_2=U*C*/postgres,role_3=U*C/role_1,=UC/role_1,=U/postgres,role_3=U*C*/postgres} + non_dist_schema | {postgres=UC/postgres,role_1=U*C*/postgres,role_2=U*C*/postgres,role_3=U*C*/postgres} +(3 rows) + +\c - - - :worker_1_port +SELECT nspname, nspacl FROM pg_namespace WHERE nspname IN ('dist_schema', 'another_dist_schema', 'non_dist_schema') ORDER BY nspname; + nspname | nspacl +--------------------------------------------------------------------- + another_dist_schema | {postgres=UC/postgres,role_1=U*C*/postgres,role_2=U*C*/postgres,role_3=U*C*/postgres} + dist_schema | {postgres=UC/postgres,role_1=U*C*/postgres,role_2=U*C*/postgres,role_3=U*C/role_1,=UC/role_1,=U/postgres,role_3=U*C*/postgres} +(2 rows) + +\c - - - :master_port +-- revoke all permissions +REVOKE ALL ON SCHEMA dist_schema, another_dist_schema, non_dist_schema FROM role_1, role_2, role_3, PUBLIC CASCADE; +SELECT nspname, nspacl FROM pg_namespace WHERE nspname IN ('dist_schema', 'another_dist_schema', 'non_dist_schema') ORDER BY nspname; + nspname | nspacl +--------------------------------------------------------------------- + another_dist_schema | {postgres=UC/postgres} + dist_schema | {postgres=UC/postgres} + non_dist_schema | {postgres=UC/postgres} +(3 rows) + +\c - - - :worker_1_port +SELECT nspname, nspacl FROM pg_namespace WHERE nspname IN ('dist_schema', 'another_dist_schema', 'non_dist_schema') ORDER BY nspname; + nspname | nspacl +--------------------------------------------------------------------- + another_dist_schema | {postgres=UC/postgres} + dist_schema | {postgres=UC/postgres} +(2 rows) + +\c - - - :master_port +-- grant with multiple permissions, roles and schemas +GRANT USAGE, CREATE ON SCHEMA dist_schema, another_dist_schema, non_dist_schema TO role_1, role_2, role_3; +SELECT nspname, nspacl FROM pg_namespace WHERE nspname IN ('dist_schema', 'another_dist_schema', 'non_dist_schema') ORDER BY nspname; + nspname | nspacl +--------------------------------------------------------------------- + another_dist_schema | {postgres=UC/postgres,role_1=UC/postgres,role_2=UC/postgres,role_3=UC/postgres} + dist_schema | {postgres=UC/postgres,role_1=UC/postgres,role_2=UC/postgres,role_3=UC/postgres} + non_dist_schema | {postgres=UC/postgres,role_1=UC/postgres,role_2=UC/postgres,role_3=UC/postgres} +(3 rows) + +\c - - - :worker_1_port +SELECT nspname, nspacl FROM pg_namespace WHERE nspname IN ('dist_schema', 'another_dist_schema', 'non_dist_schema') ORDER BY nspname; + nspname | nspacl +--------------------------------------------------------------------- + another_dist_schema | {postgres=UC/postgres,role_1=UC/postgres,role_2=UC/postgres,role_3=UC/postgres} + dist_schema | {postgres=UC/postgres,role_1=UC/postgres,role_2=UC/postgres,role_3=UC/postgres} +(2 rows) + +\c - - - :master_port +-- revoke with multiple permissions, roles and schemas +REVOKE USAGE, CREATE ON SCHEMA dist_schema, another_dist_schema, non_dist_schema FROM role_1, role_2; +SELECT nspname, nspacl FROM pg_namespace WHERE nspname IN ('dist_schema', 'another_dist_schema', 'non_dist_schema') ORDER BY nspname; + nspname | nspacl +--------------------------------------------------------------------- + another_dist_schema | {postgres=UC/postgres,role_3=UC/postgres} + dist_schema | {postgres=UC/postgres,role_3=UC/postgres} + non_dist_schema | {postgres=UC/postgres,role_3=UC/postgres} +(3 rows) + +\c - - - :worker_1_port +SELECT nspname, nspacl FROM pg_namespace WHERE nspname IN ('dist_schema', 'another_dist_schema', 'non_dist_schema') ORDER BY nspname; + nspname | nspacl +--------------------------------------------------------------------- + another_dist_schema | {postgres=UC/postgres,role_3=UC/postgres} + dist_schema | {postgres=UC/postgres,role_3=UC/postgres} +(2 rows) + +\c - - - :master_port +-- grant with grant option +GRANT USAGE ON SCHEMA dist_schema TO role_1, role_3 WITH GRANT OPTION; +\c - - - :worker_1_port +SELECT nspname, nspacl FROM pg_namespace WHERE nspname IN ('dist_schema', 'another_dist_schema', 'non_dist_schema') ORDER BY nspname; + nspname | nspacl +--------------------------------------------------------------------- + another_dist_schema | {postgres=UC/postgres,role_3=UC/postgres} + dist_schema | {postgres=UC/postgres,role_3=U*C/postgres,role_1=U*/postgres} +(2 rows) + +\c - - - :master_port +-- revoke grant option for +REVOKE GRANT OPTION FOR USAGE ON SCHEMA dist_schema FROM role_3; +\c - - - :worker_1_port +SELECT nspname, nspacl FROM pg_namespace WHERE nspname IN ('dist_schema', 'another_dist_schema', 'non_dist_schema') ORDER BY nspname; + nspname | nspacl +--------------------------------------------------------------------- + another_dist_schema | {postgres=UC/postgres,role_3=UC/postgres} + dist_schema | {postgres=UC/postgres,role_3=UC/postgres,role_1=U*/postgres} +(2 rows) + +\c - - - :master_port +-- test current_user +SET citus.enable_alter_role_propagation TO ON; +ALTER ROLE role_1 SUPERUSER; +SET citus.enable_alter_role_propagation TO OFF; +SET ROLE role_1; +GRANT CREATE ON SCHEMA dist_schema TO CURRENT_USER; +\c - - - :worker_1_port +SELECT nspname, nspacl FROM pg_namespace WHERE nspname IN ('dist_schema', 'another_dist_schema', 'non_dist_schema') ORDER BY nspname; + nspname | nspacl +--------------------------------------------------------------------- + another_dist_schema | {postgres=UC/postgres,role_3=UC/postgres} + dist_schema | {postgres=UC/postgres,role_3=UC/postgres,role_1=U*C/postgres} +(2 rows) + +\c - - - :master_port +RESET ROLE; +SET citus.enable_alter_role_propagation TO ON; +ALTER ROLE role_1 NOSUPERUSER; +SET citus.enable_alter_role_propagation TO OFF; +DROP TABLE dist_schema.dist_table, another_dist_schema.dist_table; +SELECT run_command_on_coordinator_and_workers('DROP SCHEMA dist_schema'); + run_command_on_coordinator_and_workers +--------------------------------------------------------------------- + +(1 row) + +SELECT run_command_on_coordinator_and_workers('DROP SCHEMA another_dist_schema'); + run_command_on_coordinator_and_workers +--------------------------------------------------------------------- + +(1 row) + +SELECT run_command_on_coordinator_and_workers('DROP SCHEMA non_dist_schema'); + run_command_on_coordinator_and_workers +--------------------------------------------------------------------- + +(1 row) + +-- test if the grantors are propagated correctly +-- first remove one of the worker nodes +SET citus.shard_replication_factor TO 1; +SELECT master_remove_node('localhost', :worker_2_port); + master_remove_node +--------------------------------------------------------------------- + +(1 row) + +-- create a new schema +CREATE SCHEMA grantor_schema; +-- give cascading permissions +GRANT USAGE, CREATE ON SCHEMA grantor_schema TO role_1 WITH GRANT OPTION; +GRANT CREATE ON SCHEMA grantor_schema TO PUBLIC; +SET ROLE role_1; +GRANT USAGE ON SCHEMA grantor_schema TO role_2 WITH GRANT OPTION; +GRANT CREATE ON SCHEMA grantor_schema TO role_2; +GRANT USAGE, CREATE ON SCHEMA grantor_schema TO role_3; +GRANT CREATE, USAGE ON SCHEMA grantor_schema TO PUBLIC; +SET ROLE role_2; +GRANT USAGE ON SCHEMA grantor_schema TO role_3; +RESET ROLE; +-- distribute the schema +CREATE TABLE grantor_schema.grantor_table (id INT); +SELECT create_distributed_table('grantor_schema.grantor_table', 'id'); + create_distributed_table +--------------------------------------------------------------------- + +(1 row) + +-- check if the grantors are propagated correctly +SELECT nspname, nspacl FROM pg_namespace WHERE nspname = 'grantor_schema' ORDER BY nspname; + nspname | nspacl +--------------------------------------------------------------------- + grantor_schema | {postgres=UC/postgres,role_1=U*C*/postgres,=C/postgres,role_2=U*C/role_1,role_3=UC/role_1,=UC/role_1,role_3=U/role_2} +(1 row) + +\c - - - :worker_1_port +SELECT nspname, nspacl FROM pg_namespace WHERE nspname = 'grantor_schema' ORDER BY nspname; + nspname | nspacl +--------------------------------------------------------------------- + grantor_schema | {postgres=UC/postgres,role_1=U*C*/postgres,=C/postgres,role_2=U*C/role_1,role_3=UC/role_1,=UC/role_1,role_3=U/role_2} +(1 row) + +\c - - - :master_port +-- add the previously removed node +SELECT 1 FROM master_add_node('localhost', :worker_2_port); + ?column? +--------------------------------------------------------------------- + 1 +(1 row) + +-- check if the grantors are propagated correctly +SELECT nspname, nspacl FROM pg_namespace WHERE nspname = 'grantor_schema' ORDER BY nspname; + nspname | nspacl +--------------------------------------------------------------------- + grantor_schema | {postgres=UC/postgres,role_1=U*C*/postgres,=C/postgres,role_2=U*C/role_1,role_3=UC/role_1,=UC/role_1,role_3=U/role_2} +(1 row) + +\c - - - :worker_2_port +SELECT nspname, nspacl FROM pg_namespace WHERE nspname = 'grantor_schema' ORDER BY nspname; + nspname | nspacl +--------------------------------------------------------------------- + grantor_schema | {postgres=UC/postgres,role_1=U*C*/postgres,=C/postgres,role_2=U*C/role_1,role_3=UC/role_1,=UC/role_1,role_3=U/role_2} +(1 row) + +\c - - - :master_port +-- revoke one of the permissions +REVOKE USAGE ON SCHEMA grantor_schema FROM role_1 CASCADE; +-- check if revoke worked correctly +SELECT nspname, nspacl FROM pg_namespace WHERE nspname = 'grantor_schema' ORDER BY nspname; + nspname | nspacl +--------------------------------------------------------------------- + grantor_schema | {postgres=UC/postgres,role_1=C*/postgres,=C/postgres,role_2=C/role_1,role_3=C/role_1,=C/role_1} +(1 row) + +\c - - - :worker_1_port +SELECT nspname, nspacl FROM pg_namespace WHERE nspname = 'grantor_schema' ORDER BY nspname; + nspname | nspacl +--------------------------------------------------------------------- + grantor_schema | {postgres=UC/postgres,role_1=C*/postgres,=C/postgres,role_2=C/role_1,role_3=C/role_1,=C/role_1} +(1 row) + +\c - - - :master_port +-- test if grantor propagates correctly on already distributed schemas +GRANT USAGE ON SCHEMA grantor_schema TO role_1 WITH GRANT OPTION; +SET ROLE role_1; +GRANT USAGE ON SCHEMA grantor_schema TO role_2; +GRANT USAGE ON SCHEMA grantor_schema TO role_3 WITH GRANT OPTION; +SET ROLE role_3; +GRANT USAGE ON SCHEMA grantor_schema TO role_2; +RESET ROLE; +-- check the results +SELECT nspname, nspacl FROM pg_namespace WHERE nspname = 'grantor_schema' ORDER BY nspname; + nspname | nspacl +--------------------------------------------------------------------- + grantor_schema | {postgres=UC/postgres,role_1=U*C*/postgres,=C/postgres,role_2=UC/role_1,role_3=U*C/role_1,=C/role_1,role_2=U/role_3} +(1 row) + +\c - - - :worker_1_port +SELECT nspname, nspacl FROM pg_namespace WHERE nspname = 'grantor_schema' ORDER BY nspname; + nspname | nspacl +--------------------------------------------------------------------- + grantor_schema | {postgres=UC/postgres,role_1=U*C*/postgres,=C/postgres,role_2=UC/role_1,role_3=U*C/role_1,=C/role_1,role_2=U/role_3} +(1 row) + +\c - - - :master_port +DROP TABLE grantor_schema.grantor_table; +SELECT run_command_on_coordinator_and_workers('DROP SCHEMA grantor_schema CASCADE'); + run_command_on_coordinator_and_workers +--------------------------------------------------------------------- + +(1 row) + +-- test distributing the schema with another user +CREATE SCHEMA dist_schema; +GRANT ALL ON SCHEMA dist_schema TO role_1 WITH GRANT OPTION; +SET ROLE role_1; +GRANT ALL ON SCHEMA dist_schema TO role_2 WITH GRANT OPTION; +CREATE TABLE dist_schema.dist_table (id int); +SELECT create_distributed_table('dist_schema.dist_table', 'id'); + create_distributed_table +--------------------------------------------------------------------- + +(1 row) + +SELECT nspname, nspacl FROM pg_namespace WHERE nspname = 'dist_schema' ORDER BY nspname; + nspname | nspacl +--------------------------------------------------------------------- + dist_schema | {postgres=UC/postgres,role_1=U*C*/postgres,role_2=U*C*/role_1} +(1 row) + +\c - - - :worker_1_port +SELECT nspname, nspacl FROM pg_namespace WHERE nspname = 'dist_schema' ORDER BY nspname; + nspname | nspacl +--------------------------------------------------------------------- + dist_schema | {postgres=UC/postgres,role_1=U*C*/postgres,role_2=U*C*/role_1} +(1 row) + +\c - - - :master_port +DROP TABLE dist_schema.dist_table; +SELECT run_command_on_coordinator_and_workers('DROP SCHEMA dist_schema CASCADE'); + run_command_on_coordinator_and_workers +--------------------------------------------------------------------- + +(1 row) + +SELECT run_command_on_coordinator_and_workers('DROP ROLE role_1, role_2, role_3'); + run_command_on_coordinator_and_workers +--------------------------------------------------------------------- + +(1 row) + diff --git a/src/test/regress/multi_schedule b/src/test/regress/multi_schedule index 4fc14f907..aa5eb2927 100644 --- a/src/test/regress/multi_schedule +++ b/src/test/regress/multi_schedule @@ -222,8 +222,10 @@ test: multi_metadata_sync test: multi_unsupported_worker_operations # ---------- +# grant_on_schema_propagation tests if the GRANT ... ON SCHEMA queries are propagated correctly # multi_schema_support makes sure we can work with tables in schemas other than public with no problem # ---------- +test: grant_on_schema_propagation test: multi_schema_support # ---------- diff --git a/src/test/regress/sql/grant_on_schema_propagation.sql b/src/test/regress/sql/grant_on_schema_propagation.sql new file mode 100644 index 000000000..41da0e640 --- /dev/null +++ b/src/test/regress/sql/grant_on_schema_propagation.sql @@ -0,0 +1,177 @@ +-- +-- GRANT_ON_SCHEMA_PROPAGATION +-- + +-- test grants are propagated when the schema is +CREATE SCHEMA dist_schema; +CREATE TABLE dist_schema.dist_table (id int); +CREATE SCHEMA another_dist_schema; +CREATE TABLE another_dist_schema.dist_table (id int); +CREATE SCHEMA non_dist_schema; + +-- create roles on all nodes +SELECT run_command_on_coordinator_and_workers('CREATE USER role_1'); +SELECT run_command_on_coordinator_and_workers('CREATE USER role_2'); +SELECT run_command_on_coordinator_and_workers('CREATE USER role_3'); + +-- do some varying grants +GRANT USAGE, CREATE ON SCHEMA dist_schema TO role_1 WITH GRANT OPTION; +GRANT USAGE ON SCHEMA dist_schema TO role_2; +SET ROLE role_1; +GRANT USAGE ON SCHEMA dist_schema TO role_3 WITH GRANT OPTION; +GRANT CREATE ON SCHEMA dist_schema TO role_3; +GRANT CREATE, USAGE ON SCHEMA dist_schema TO PUBLIC; +RESET ROLE; +GRANT USAGE ON SCHEMA dist_schema TO PUBLIC; + +SELECT create_distributed_table('dist_schema.dist_table', 'id'); +SELECT create_distributed_table('another_dist_schema.dist_table', 'id'); + +SELECT nspname, nspacl FROM pg_namespace WHERE nspname = 'dist_schema'; +\c - - - :worker_1_port +SELECT nspname, nspacl FROM pg_namespace WHERE nspname = 'dist_schema'; +\c - - - :master_port + +-- grant all permissions +GRANT ALL ON SCHEMA dist_schema, another_dist_schema, non_dist_schema TO role_1, role_2, role_3 WITH GRANT OPTION; +SELECT nspname, nspacl FROM pg_namespace WHERE nspname IN ('dist_schema', 'another_dist_schema', 'non_dist_schema') ORDER BY nspname; +\c - - - :worker_1_port +SELECT nspname, nspacl FROM pg_namespace WHERE nspname IN ('dist_schema', 'another_dist_schema', 'non_dist_schema') ORDER BY nspname; +\c - - - :master_port + +-- revoke all permissions +REVOKE ALL ON SCHEMA dist_schema, another_dist_schema, non_dist_schema FROM role_1, role_2, role_3, PUBLIC CASCADE; +SELECT nspname, nspacl FROM pg_namespace WHERE nspname IN ('dist_schema', 'another_dist_schema', 'non_dist_schema') ORDER BY nspname; +\c - - - :worker_1_port +SELECT nspname, nspacl FROM pg_namespace WHERE nspname IN ('dist_schema', 'another_dist_schema', 'non_dist_schema') ORDER BY nspname; +\c - - - :master_port + +-- grant with multiple permissions, roles and schemas +GRANT USAGE, CREATE ON SCHEMA dist_schema, another_dist_schema, non_dist_schema TO role_1, role_2, role_3; +SELECT nspname, nspacl FROM pg_namespace WHERE nspname IN ('dist_schema', 'another_dist_schema', 'non_dist_schema') ORDER BY nspname; +\c - - - :worker_1_port +SELECT nspname, nspacl FROM pg_namespace WHERE nspname IN ('dist_schema', 'another_dist_schema', 'non_dist_schema') ORDER BY nspname; +\c - - - :master_port + +-- revoke with multiple permissions, roles and schemas +REVOKE USAGE, CREATE ON SCHEMA dist_schema, another_dist_schema, non_dist_schema FROM role_1, role_2; +SELECT nspname, nspacl FROM pg_namespace WHERE nspname IN ('dist_schema', 'another_dist_schema', 'non_dist_schema') ORDER BY nspname; +\c - - - :worker_1_port +SELECT nspname, nspacl FROM pg_namespace WHERE nspname IN ('dist_schema', 'another_dist_schema', 'non_dist_schema') ORDER BY nspname; +\c - - - :master_port + +-- grant with grant option +GRANT USAGE ON SCHEMA dist_schema TO role_1, role_3 WITH GRANT OPTION; +\c - - - :worker_1_port +SELECT nspname, nspacl FROM pg_namespace WHERE nspname IN ('dist_schema', 'another_dist_schema', 'non_dist_schema') ORDER BY nspname; +\c - - - :master_port + +-- revoke grant option for +REVOKE GRANT OPTION FOR USAGE ON SCHEMA dist_schema FROM role_3; +\c - - - :worker_1_port +SELECT nspname, nspacl FROM pg_namespace WHERE nspname IN ('dist_schema', 'another_dist_schema', 'non_dist_schema') ORDER BY nspname; +\c - - - :master_port + +-- test current_user +SET citus.enable_alter_role_propagation TO ON; +ALTER ROLE role_1 SUPERUSER; +SET citus.enable_alter_role_propagation TO OFF; +SET ROLE role_1; +GRANT CREATE ON SCHEMA dist_schema TO CURRENT_USER; +\c - - - :worker_1_port +SELECT nspname, nspacl FROM pg_namespace WHERE nspname IN ('dist_schema', 'another_dist_schema', 'non_dist_schema') ORDER BY nspname; +\c - - - :master_port +RESET ROLE; +SET citus.enable_alter_role_propagation TO ON; +ALTER ROLE role_1 NOSUPERUSER; +SET citus.enable_alter_role_propagation TO OFF; + +DROP TABLE dist_schema.dist_table, another_dist_schema.dist_table; +SELECT run_command_on_coordinator_and_workers('DROP SCHEMA dist_schema'); +SELECT run_command_on_coordinator_and_workers('DROP SCHEMA another_dist_schema'); +SELECT run_command_on_coordinator_and_workers('DROP SCHEMA non_dist_schema'); + +-- test if the grantors are propagated correctly +-- first remove one of the worker nodes +SET citus.shard_replication_factor TO 1; +SELECT master_remove_node('localhost', :worker_2_port); + +-- create a new schema +CREATE SCHEMA grantor_schema; + +-- give cascading permissions +GRANT USAGE, CREATE ON SCHEMA grantor_schema TO role_1 WITH GRANT OPTION; +GRANT CREATE ON SCHEMA grantor_schema TO PUBLIC; +SET ROLE role_1; +GRANT USAGE ON SCHEMA grantor_schema TO role_2 WITH GRANT OPTION; +GRANT CREATE ON SCHEMA grantor_schema TO role_2; +GRANT USAGE, CREATE ON SCHEMA grantor_schema TO role_3; +GRANT CREATE, USAGE ON SCHEMA grantor_schema TO PUBLIC; +SET ROLE role_2; +GRANT USAGE ON SCHEMA grantor_schema TO role_3; +RESET ROLE; + +-- distribute the schema +CREATE TABLE grantor_schema.grantor_table (id INT); +SELECT create_distributed_table('grantor_schema.grantor_table', 'id'); + +-- check if the grantors are propagated correctly +SELECT nspname, nspacl FROM pg_namespace WHERE nspname = 'grantor_schema' ORDER BY nspname; +\c - - - :worker_1_port +SELECT nspname, nspacl FROM pg_namespace WHERE nspname = 'grantor_schema' ORDER BY nspname; +\c - - - :master_port + +-- add the previously removed node +SELECT 1 FROM master_add_node('localhost', :worker_2_port); + +-- check if the grantors are propagated correctly +SELECT nspname, nspacl FROM pg_namespace WHERE nspname = 'grantor_schema' ORDER BY nspname; +\c - - - :worker_2_port +SELECT nspname, nspacl FROM pg_namespace WHERE nspname = 'grantor_schema' ORDER BY nspname; +\c - - - :master_port + +-- revoke one of the permissions +REVOKE USAGE ON SCHEMA grantor_schema FROM role_1 CASCADE; + +-- check if revoke worked correctly +SELECT nspname, nspacl FROM pg_namespace WHERE nspname = 'grantor_schema' ORDER BY nspname; +\c - - - :worker_1_port +SELECT nspname, nspacl FROM pg_namespace WHERE nspname = 'grantor_schema' ORDER BY nspname; +\c - - - :master_port + +-- test if grantor propagates correctly on already distributed schemas +GRANT USAGE ON SCHEMA grantor_schema TO role_1 WITH GRANT OPTION; +SET ROLE role_1; +GRANT USAGE ON SCHEMA grantor_schema TO role_2; +GRANT USAGE ON SCHEMA grantor_schema TO role_3 WITH GRANT OPTION; +SET ROLE role_3; +GRANT USAGE ON SCHEMA grantor_schema TO role_2; +RESET ROLE; + +-- check the results +SELECT nspname, nspacl FROM pg_namespace WHERE nspname = 'grantor_schema' ORDER BY nspname; +\c - - - :worker_1_port +SELECT nspname, nspacl FROM pg_namespace WHERE nspname = 'grantor_schema' ORDER BY nspname; +\c - - - :master_port + +DROP TABLE grantor_schema.grantor_table; +SELECT run_command_on_coordinator_and_workers('DROP SCHEMA grantor_schema CASCADE'); + +-- test distributing the schema with another user +CREATE SCHEMA dist_schema; + +GRANT ALL ON SCHEMA dist_schema TO role_1 WITH GRANT OPTION; +SET ROLE role_1; +GRANT ALL ON SCHEMA dist_schema TO role_2 WITH GRANT OPTION; + +CREATE TABLE dist_schema.dist_table (id int); +SELECT create_distributed_table('dist_schema.dist_table', 'id'); + +SELECT nspname, nspacl FROM pg_namespace WHERE nspname = 'dist_schema' ORDER BY nspname; +\c - - - :worker_1_port +SELECT nspname, nspacl FROM pg_namespace WHERE nspname = 'dist_schema' ORDER BY nspname; +\c - - - :master_port + +DROP TABLE dist_schema.dist_table; +SELECT run_command_on_coordinator_and_workers('DROP SCHEMA dist_schema CASCADE'); +SELECT run_command_on_coordinator_and_workers('DROP ROLE role_1, role_2, role_3');