mirror of https://github.com/citusdata/citus.git
Merge branch 'main' into sanitizer_7943_main
commit
dd7b79f4dc
|
@ -17,6 +17,7 @@
|
|||
#include "distributed/citus_ruleutils.h"
|
||||
#include "distributed/commands.h"
|
||||
#include "distributed/commands/utility_hook.h"
|
||||
#include "distributed/deparser.h"
|
||||
#include "distributed/metadata/distobject.h"
|
||||
#include "distributed/metadata_cache.h"
|
||||
#include "distributed/version_compat.h"
|
||||
|
@ -32,7 +33,6 @@ static List * CollectGrantTableIdList(GrantStmt *grantStmt);
|
|||
* needed during the worker node portion of DDL execution before returning the
|
||||
* DDLJobs in a List. If no distributed table is involved, this returns NIL.
|
||||
*
|
||||
* NB: So far column level privileges are not supported.
|
||||
*/
|
||||
List *
|
||||
PreprocessGrantStmt(Node *node, const char *queryString,
|
||||
|
@ -70,9 +70,12 @@ PreprocessGrantStmt(Node *node, const char *queryString,
|
|||
return NIL;
|
||||
}
|
||||
|
||||
EnsureCoordinator();
|
||||
|
||||
/* deparse the privileges */
|
||||
if (grantStmt->privileges == NIL)
|
||||
{
|
||||
/* this is used for table level only */
|
||||
appendStringInfo(&privsString, "ALL");
|
||||
}
|
||||
else
|
||||
|
@ -88,18 +91,44 @@ PreprocessGrantStmt(Node *node, const char *queryString,
|
|||
{
|
||||
appendStringInfoString(&privsString, ", ");
|
||||
}
|
||||
|
||||
if (priv->priv_name)
|
||||
{
|
||||
appendStringInfo(&privsString, "%s", priv->priv_name);
|
||||
}
|
||||
/*
|
||||
* ALL can only be set alone.
|
||||
* And ALL is not added as a keyword in priv_name by parser, but
|
||||
* because there are column(s) defined, a grantStmt->privileges is
|
||||
* defined. So we need to handle this special case here (see if
|
||||
* condition above).
|
||||
*/
|
||||
else if (isFirst)
|
||||
{
|
||||
/* this is used for column level only */
|
||||
appendStringInfo(&privsString, "ALL");
|
||||
}
|
||||
/*
|
||||
* Instead of relying only on the syntax check done by Postgres and
|
||||
* adding an assert here, add a default ERROR if ALL is not first
|
||||
* and no priv_name is defined.
|
||||
*/
|
||||
else
|
||||
{
|
||||
ereport(ERROR, (errcode(ERRCODE_INTERNAL_ERROR),
|
||||
errmsg("Cannot parse GRANT/REVOKE privileges")));
|
||||
}
|
||||
|
||||
isFirst = false;
|
||||
|
||||
if (priv->cols != NIL)
|
||||
{
|
||||
ereport(ERROR, (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
|
||||
errmsg("grant/revoke on column list is currently "
|
||||
"unsupported")));
|
||||
StringInfoData colsString;
|
||||
initStringInfo(&colsString);
|
||||
|
||||
AppendColumnNameList(&colsString, priv->cols);
|
||||
appendStringInfo(&privsString, "%s", colsString.data);
|
||||
}
|
||||
|
||||
Assert(priv->priv_name != NULL);
|
||||
|
||||
appendStringInfo(&privsString, "%s", priv->priv_name);
|
||||
}
|
||||
}
|
||||
|
||||
|
|
|
@ -83,6 +83,8 @@ static void AppendStorageParametersToString(StringInfo stringBuffer,
|
|||
static const char * convert_aclright_to_string(int aclright);
|
||||
static void simple_quote_literal(StringInfo buf, const char *val);
|
||||
static void AddVacuumParams(ReindexStmt *reindexStmt, StringInfo buffer);
|
||||
static void process_acl_items(Acl *acl, const char *relationName,
|
||||
const char *attributeName, List **defs);
|
||||
|
||||
|
||||
/*
|
||||
|
@ -1110,9 +1112,8 @@ pg_get_indexclusterdef_string(Oid indexRelationId)
|
|||
|
||||
/*
|
||||
* pg_get_table_grants returns a list of sql statements which recreate the
|
||||
* permissions for a specific table.
|
||||
* permissions for a specific table, including attributes privileges.
|
||||
*
|
||||
* This function is modeled after aclexplode(), don't change too heavily.
|
||||
*/
|
||||
List *
|
||||
pg_get_table_grants(Oid relationId)
|
||||
|
@ -1136,6 +1137,8 @@ pg_get_table_grants(Oid relationId)
|
|||
errmsg("relation with OID %u does not exist",
|
||||
relationId)));
|
||||
}
|
||||
Form_pg_class classForm = (Form_pg_class) GETSTRUCT(classTuple);
|
||||
AttrNumber nattrs = classForm->relnatts;
|
||||
|
||||
Datum aclDatum = SysCacheGetAttr(RELOID, classTuple, Anum_pg_class_relacl,
|
||||
&isNull);
|
||||
|
@ -1163,80 +1166,132 @@ pg_get_table_grants(Oid relationId)
|
|||
/* iterate through the acl datastructure, emit GRANTs */
|
||||
|
||||
Acl *acl = DatumGetAclP(aclDatum);
|
||||
AclItem *aidat = ACL_DAT(acl);
|
||||
|
||||
int offtype = -1;
|
||||
int i = 0;
|
||||
while (i < ACL_NUM(acl))
|
||||
process_acl_items(acl, relationName, NULL, &defs);
|
||||
|
||||
/* if we have a detoasted copy, free it */
|
||||
if ((Pointer) acl != DatumGetPointer(aclDatum))
|
||||
pfree(acl);
|
||||
}
|
||||
|
||||
resetStringInfo(&buffer);
|
||||
|
||||
/* lookup all attribute level grants */
|
||||
for (AttrNumber attNum = 1; attNum <= nattrs; attNum++)
|
||||
{
|
||||
HeapTuple attTuple = SearchSysCache2(ATTNUM, ObjectIdGetDatum(relationId),
|
||||
Int16GetDatum(attNum));
|
||||
if (!HeapTupleIsValid(attTuple))
|
||||
{
|
||||
AclItem *aidata = NULL;
|
||||
AclMode priv_bit = 0;
|
||||
ereport(ERROR,
|
||||
(errcode(ERRCODE_UNDEFINED_COLUMN),
|
||||
errmsg("attribute with OID %u does not exist",
|
||||
attNum)));
|
||||
}
|
||||
|
||||
offtype++;
|
||||
Form_pg_attribute thisAttribute = (Form_pg_attribute) GETSTRUCT(attTuple);
|
||||
|
||||
if (offtype == N_ACL_RIGHTS)
|
||||
/* ignore dropped columns */
|
||||
if (thisAttribute->attisdropped)
|
||||
{
|
||||
ReleaseSysCache(attTuple);
|
||||
continue;
|
||||
}
|
||||
|
||||
Datum aclAttDatum = SysCacheGetAttr(ATTNUM, attTuple, Anum_pg_attribute_attacl,
|
||||
&isNull);
|
||||
if (!isNull)
|
||||
{
|
||||
/* iterate through the acl datastructure, emit GRANTs */
|
||||
Acl *acl = DatumGetAclP(aclAttDatum);
|
||||
|
||||
process_acl_items(acl, relationName, NameStr(thisAttribute->attname), &defs);
|
||||
|
||||
/* if we have a detoasted copy, free it */
|
||||
if ((Pointer) acl != DatumGetPointer(aclAttDatum))
|
||||
pfree(acl);
|
||||
}
|
||||
ReleaseSysCache(attTuple);
|
||||
}
|
||||
|
||||
relation_close(relation, NoLock);
|
||||
return defs;
|
||||
}
|
||||
|
||||
|
||||
/*
|
||||
* Helper function to process ACL items.
|
||||
* If attributeName is NULL, the function emits table-level GRANT commands;
|
||||
* otherwise it emits column-level GRANT commands.
|
||||
* This function was modeled after aclexplode(), previously in pg_get_table_grants().
|
||||
*/
|
||||
static void
|
||||
process_acl_items(Acl *acl, const char *relationName, const char *attributeName,
|
||||
List **defs)
|
||||
{
|
||||
AclItem *aidat = ACL_DAT(acl);
|
||||
int i = 0;
|
||||
int offtype = -1;
|
||||
StringInfoData buffer;
|
||||
|
||||
initStringInfo(&buffer);
|
||||
|
||||
while (i < ACL_NUM(acl))
|
||||
{
|
||||
offtype++;
|
||||
if (offtype == N_ACL_RIGHTS)
|
||||
{
|
||||
offtype = 0;
|
||||
i++;
|
||||
if (i >= ACL_NUM(acl)) /* done */
|
||||
{
|
||||
offtype = 0;
|
||||
i++;
|
||||
if (i >= ACL_NUM(acl)) /* done */
|
||||
{
|
||||
break;
|
||||
}
|
||||
break;
|
||||
}
|
||||
}
|
||||
|
||||
AclItem *aidata = &aidat[i];
|
||||
AclMode priv_bit = 1 << offtype;
|
||||
|
||||
if (ACLITEM_GET_PRIVS(*aidata) & priv_bit)
|
||||
{
|
||||
const char *roleName = NULL;
|
||||
const char *withGrant = "";
|
||||
|
||||
if (aidata->ai_grantee != 0)
|
||||
{
|
||||
roleName = quote_identifier(GetUserNameFromId(aidata->ai_grantee, false));
|
||||
}
|
||||
else
|
||||
{
|
||||
roleName = "PUBLIC";
|
||||
}
|
||||
|
||||
aidata = &aidat[i];
|
||||
priv_bit = 1 << offtype;
|
||||
|
||||
if (ACLITEM_GET_PRIVS(*aidata) & priv_bit)
|
||||
if ((ACLITEM_GET_GOPTIONS(*aidata) & priv_bit) != 0)
|
||||
{
|
||||
const char *roleName = NULL;
|
||||
const char *withGrant = "";
|
||||
|
||||
if (aidata->ai_grantee != 0)
|
||||
{
|
||||
|
||||
HeapTuple htup = SearchSysCache1(AUTHOID, ObjectIdGetDatum(aidata->ai_grantee));
|
||||
if (HeapTupleIsValid(htup))
|
||||
{
|
||||
Form_pg_authid authForm = ((Form_pg_authid) GETSTRUCT(htup));
|
||||
|
||||
roleName = quote_identifier(NameStr(authForm->rolname));
|
||||
|
||||
ReleaseSysCache(htup);
|
||||
}
|
||||
else
|
||||
{
|
||||
elog(ERROR, "cache lookup failed for role %u", aidata->ai_grantee);
|
||||
}
|
||||
}
|
||||
else
|
||||
{
|
||||
roleName = "PUBLIC";
|
||||
}
|
||||
|
||||
if ((ACLITEM_GET_GOPTIONS(*aidata) & priv_bit) != 0)
|
||||
{
|
||||
withGrant = " WITH GRANT OPTION";
|
||||
}
|
||||
withGrant = " WITH GRANT OPTION";
|
||||
}
|
||||
|
||||
if (attributeName)
|
||||
{
|
||||
appendStringInfo(&buffer, "GRANT %s(%s) ON %s TO %s%s",
|
||||
convert_aclright_to_string(priv_bit),
|
||||
quote_identifier(attributeName),
|
||||
relationName,
|
||||
roleName,
|
||||
withGrant);
|
||||
}
|
||||
else
|
||||
{
|
||||
appendStringInfo(&buffer, "GRANT %s ON %s TO %s%s",
|
||||
convert_aclright_to_string(priv_bit),
|
||||
relationName,
|
||||
roleName,
|
||||
withGrant);
|
||||
|
||||
defs = lappend(defs, pstrdup(buffer.data));
|
||||
|
||||
resetStringInfo(&buffer);
|
||||
}
|
||||
*defs = lappend(*defs, pstrdup(buffer.data));
|
||||
resetStringInfo(&buffer);
|
||||
}
|
||||
}
|
||||
|
||||
resetStringInfo(&buffer);
|
||||
|
||||
relation_close(relation, NoLock);
|
||||
return defs;
|
||||
/* *INDENT-ON* */
|
||||
}
|
||||
|
||||
|
||||
|
|
|
@ -2428,14 +2428,32 @@ UpdateNoneDistTableMetadata(Oid relationId, char replicationModel, uint32 coloca
|
|||
|
||||
|
||||
/*
|
||||
* Check that the current user has `mode` permissions on relationId, error out
|
||||
* if not. Superusers always have such permissions.
|
||||
* Check that the current user has `mode` permissions on relationId.
|
||||
* If not, also check relationId's attributes with `mask`, error out
|
||||
* privileges are not defined.
|
||||
* ACL mask is used because we assume that user has enough privilege
|
||||
* to distribute a table when either ACL_INSERT on the TABLE or
|
||||
* ACL_INSERT on ALL attributes.
|
||||
* In other situations, having a single attribute privilege is enough.
|
||||
* Superusers always have such permissions.
|
||||
*/
|
||||
void
|
||||
EnsureTablePermissions(Oid relationId, AclMode mode)
|
||||
EnsureTablePermissions(Oid relationId, AclMode mode, AclMaskHow mask)
|
||||
{
|
||||
AclResult aclresult = pg_class_aclcheck(relationId, GetUserId(), mode);
|
||||
|
||||
if (aclresult == ACLCHECK_OK)
|
||||
{
|
||||
return;
|
||||
}
|
||||
|
||||
/*
|
||||
* Also check the attributes: for example "GRANT ALL(a)" has no table level
|
||||
* right but user is still allowed to lock table as needed. PostgreSQL will
|
||||
* still enforce ACL later so it's safe.
|
||||
*/
|
||||
aclresult = pg_attribute_aclcheck_all(relationId, GetUserId(), mode, mask);
|
||||
|
||||
if (aclresult != ACLCHECK_OK)
|
||||
{
|
||||
aclcheck_error(aclresult, OBJECT_TABLE, get_rel_name(relationId));
|
||||
|
|
|
@ -1522,7 +1522,7 @@ get_shard_id_for_distribution_column(PG_FUNCTION_ARGS)
|
|||
}
|
||||
|
||||
Oid relationId = PG_GETARG_OID(0);
|
||||
EnsureTablePermissions(relationId, ACL_SELECT);
|
||||
EnsureTablePermissions(relationId, ACL_SELECT, ACLMASK_ANY);
|
||||
|
||||
if (!IsCitusTable(relationId))
|
||||
{
|
||||
|
|
|
@ -108,7 +108,7 @@ master_create_empty_shard(PG_FUNCTION_ARGS)
|
|||
|
||||
Oid relationId = ResolveRelationId(relationNameText, false);
|
||||
|
||||
EnsureTablePermissions(relationId, ACL_INSERT);
|
||||
EnsureTablePermissions(relationId, ACL_INSERT, ACLMASK_ALL);
|
||||
CheckDistributedTable(relationId);
|
||||
|
||||
/*
|
||||
|
|
|
@ -222,10 +222,12 @@ lock_shard_resources(PG_FUNCTION_ARGS)
|
|||
* on the executor. However, for INSERTs, the user might have only
|
||||
* INSERTs granted, so add a special case for it.
|
||||
*/
|
||||
AclMode aclMask = ACL_UPDATE | ACL_DELETE | ACL_TRUNCATE;
|
||||
AclMode aclMode = ACL_UPDATE | ACL_DELETE | ACL_TRUNCATE;
|
||||
AclMaskHow aclMaskHow = ACLMASK_ANY;
|
||||
|
||||
if (lockMode == RowExclusiveLock)
|
||||
{
|
||||
aclMask |= ACL_INSERT;
|
||||
aclMode |= ACL_INSERT;
|
||||
}
|
||||
|
||||
for (int shardIdIndex = 0; shardIdIndex < shardIdCount; shardIdIndex++)
|
||||
|
@ -254,7 +256,7 @@ lock_shard_resources(PG_FUNCTION_ARGS)
|
|||
|
||||
if (!SkipAdvisoryLockPermissionChecks)
|
||||
{
|
||||
EnsureTablePermissions(relationId, aclMask);
|
||||
EnsureTablePermissions(relationId, aclMode, aclMaskHow);
|
||||
}
|
||||
|
||||
LockShardResource(shardId, lockMode);
|
||||
|
|
|
@ -400,7 +400,7 @@ extern bool ShouldPropagateAnyObject(List *addresses);
|
|||
/* Remaining metadata utility functions */
|
||||
extern Oid TableOwnerOid(Oid relationId);
|
||||
extern char * TableOwner(Oid relationId);
|
||||
extern void EnsureTablePermissions(Oid relationId, AclMode mode);
|
||||
extern void EnsureTablePermissions(Oid relationId, AclMode mode, AclMaskHow mask);
|
||||
extern void EnsureTableOwner(Oid relationId);
|
||||
extern void EnsureHashDistributedTable(Oid relationId);
|
||||
extern void EnsureHashOrSingleShardDistributedTable(Oid relationId);
|
||||
|
|
|
@ -0,0 +1,930 @@
|
|||
-- PostgreSQL 17 introduces MAINTAIN privilege, this change the default output
|
||||
-- of some test queries.
|
||||
--
|
||||
-- Alternative "grant_on_table_propagation_0.out" and this comment can be
|
||||
-- removed when support for PostgreSQL versions < 17 is dropped.
|
||||
SHOW server_version \gset
|
||||
SELECT substring(:'server_version', '\d+')::int >= 17 AS server_version_ge_17;
|
||||
server_version_ge_17
|
||||
---------------------------------------------------------------------
|
||||
t
|
||||
(1 row)
|
||||
|
||||
--
|
||||
-- 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 on all nodes and 2 managed by citus
|
||||
-- null_privs ACL must not be updated in anyway.
|
||||
CREATE TABLE dist_table (id bigint GENERATED BY DEFAULT AS IDENTITY primary key
|
||||
, test_a int -- test for INSERT
|
||||
, test_r text -- test for SELECT
|
||||
, test_w text -- test for UPDATE
|
||||
, test_mix int -- test for ALL/mixed
|
||||
, null_privs text
|
||||
);
|
||||
SELECT create_distributed_table('dist_table', 'id');
|
||||
create_distributed_table
|
||||
---------------------------------------------------------------------
|
||||
|
||||
(1 row)
|
||||
|
||||
CREATE TABLE ref_table (id bigint GENERATED BY DEFAULT AS IDENTITY primary key
|
||||
, test_a int -- test for INSERT
|
||||
, test_r text -- test for SELECT
|
||||
, test_w text -- test for UPDATE
|
||||
, test_mix int -- test for ALL
|
||||
, null_privs text
|
||||
);
|
||||
SELECT create_reference_table('ref_table');
|
||||
create_reference_table
|
||||
---------------------------------------------------------------------
|
||||
|
||||
(1 row)
|
||||
|
||||
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)');
|
||||
result
|
||||
---------------------------------------------------------------------
|
||||
CREATE TABLE
|
||||
CREATE TABLE
|
||||
CREATE TABLE
|
||||
(3 rows)
|
||||
|
||||
-- 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 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
|
||||
--
|
||||
--
|
||||
-- when executing a table level grant, "postgres" is add/listed in pg_class.relacl
|
||||
-- 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;
|
||||
-- not granted yet:
|
||||
SELECT test_r FROM ref_table;
|
||||
ERROR: permission denied for table ref_table
|
||||
RESET ROLE;
|
||||
GRANT SELECT (test_r) ON ref_table TO grant_user_0;
|
||||
SET ROLE grant_user_0;
|
||||
-- granted:
|
||||
SELECT test_r FROM ref_table;
|
||||
test_r
|
||||
---------------------------------------------------------------------
|
||||
(0 rows)
|
||||
|
||||
-- not granted:
|
||||
SELECT test_a FROM ref_table;
|
||||
ERROR: permission denied for table ref_table
|
||||
SET ROLE grant_user_1;
|
||||
-- not granted:
|
||||
SELECT test_r FROM ref_table;
|
||||
ERROR: permission denied for table ref_table
|
||||
RESET ROLE;
|
||||
-- check on coordinator and workers
|
||||
:verify_grant_table ;
|
||||
nodeport | unnest
|
||||
---------------------------------------------------------------------
|
||||
57636 | (dist_table,)
|
||||
57637 | (dist_table,)
|
||||
57638 | (dist_table,)
|
||||
57636 | (local_table,)
|
||||
57637 | (local_table,)
|
||||
57638 | (local_table,)
|
||||
57636 | (ref_table,{postgres=arwdDxtm/postgres})
|
||||
57637 | (ref_table,{postgres=arwdDxtm/postgres})
|
||||
57638 | (ref_table,{postgres=arwdDxtm/postgres})
|
||||
(9 rows)
|
||||
|
||||
:verify_grant_attributes ;
|
||||
nodeport | unnest
|
||||
---------------------------------------------------------------------
|
||||
57636 | (grant_on_table.ref_table,test_r,{grant_user_0=r/postgres})
|
||||
57637 | (grant_on_table.ref_table,test_r,{grant_user_0=r/postgres})
|
||||
57638 | (grant_on_table.ref_table,test_r,{grant_user_0=r/postgres})
|
||||
(3 rows)
|
||||
|
||||
-- cleanup
|
||||
REVOKE SELECT (test_r) ON ref_table FROM grant_user_0;
|
||||
-- check on coordinator and workers
|
||||
:verify_grant_table ;
|
||||
nodeport | unnest
|
||||
---------------------------------------------------------------------
|
||||
57636 | (dist_table,)
|
||||
57637 | (dist_table,)
|
||||
57638 | (dist_table,)
|
||||
57636 | (local_table,)
|
||||
57637 | (local_table,)
|
||||
57638 | (local_table,)
|
||||
57636 | (ref_table,{postgres=arwdDxtm/postgres})
|
||||
57637 | (ref_table,{postgres=arwdDxtm/postgres})
|
||||
57638 | (ref_table,{postgres=arwdDxtm/postgres})
|
||||
(9 rows)
|
||||
|
||||
:verify_grant_attributes ;
|
||||
nodeport | unnest
|
||||
---------------------------------------------------------------------
|
||||
(0 rows)
|
||||
|
||||
--
|
||||
-- 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;
|
||||
-- not granted yet:
|
||||
INSERT INTO ref_table (test_a) VALUES (1);
|
||||
ERROR: permission denied for table ref_table
|
||||
RESET ROLE;
|
||||
-- we would prefer not have to grant INSERT (id) as expected in the standard but
|
||||
-- Citus rewrite queries with such attributes, which prevent standard to be applied.
|
||||
GRANT INSERT (id, test_a), UPDATE (test_w, test_mix) ON ref_table, dist_table TO grant_user_0, grant_user_1;
|
||||
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);
|
||||
ERROR: permission denied for table ref_table
|
||||
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;
|
||||
-- check on coordinator and workers
|
||||
:verify_grant_table ;
|
||||
nodeport | unnest
|
||||
---------------------------------------------------------------------
|
||||
57636 | (dist_table,)
|
||||
57637 | (dist_table,)
|
||||
57638 | (dist_table,)
|
||||
57636 | (local_table,)
|
||||
57637 | (local_table,)
|
||||
57638 | (local_table,)
|
||||
57636 | (ref_table,{postgres=arwdDxtm/postgres})
|
||||
57637 | (ref_table,{postgres=arwdDxtm/postgres})
|
||||
57638 | (ref_table,{postgres=arwdDxtm/postgres})
|
||||
(9 rows)
|
||||
|
||||
:verify_grant_attributes ;
|
||||
nodeport | unnest
|
||||
---------------------------------------------------------------------
|
||||
57636 | (grant_on_table.dist_table,id,"{grant_user_0=a/postgres,grant_user_1=a/postgres}")
|
||||
57637 | (grant_on_table.dist_table,id,"{grant_user_0=a/postgres,grant_user_1=a/postgres}")
|
||||
57638 | (grant_on_table.dist_table,id,"{grant_user_0=a/postgres,grant_user_1=a/postgres}")
|
||||
57636 | (grant_on_table.dist_table,test_a,"{grant_user_0=a/postgres,grant_user_1=a/postgres}")
|
||||
57637 | (grant_on_table.dist_table,test_a,"{grant_user_0=a/postgres,grant_user_1=a/postgres}")
|
||||
57638 | (grant_on_table.dist_table,test_a,"{grant_user_0=a/postgres,grant_user_1=a/postgres}")
|
||||
57636 | (grant_on_table.dist_table,test_mix,"{grant_user_0=w/postgres,grant_user_1=w/postgres}")
|
||||
57637 | (grant_on_table.dist_table,test_mix,"{grant_user_0=w/postgres,grant_user_1=w/postgres}")
|
||||
57638 | (grant_on_table.dist_table,test_mix,"{grant_user_0=w/postgres,grant_user_1=w/postgres}")
|
||||
57636 | (grant_on_table.dist_table,test_w,"{grant_user_0=w/postgres,grant_user_1=w/postgres}")
|
||||
57637 | (grant_on_table.dist_table,test_w,"{grant_user_0=w/postgres,grant_user_1=w/postgres}")
|
||||
57638 | (grant_on_table.dist_table,test_w,"{grant_user_0=w/postgres,grant_user_1=w/postgres}")
|
||||
57636 | (grant_on_table.ref_table,id,"{grant_user_0=a/postgres,grant_user_1=a/postgres}")
|
||||
57637 | (grant_on_table.ref_table,id,"{grant_user_0=a/postgres,grant_user_1=a/postgres}")
|
||||
57638 | (grant_on_table.ref_table,id,"{grant_user_0=a/postgres,grant_user_1=a/postgres}")
|
||||
57636 | (grant_on_table.ref_table,test_a,"{grant_user_0=a/postgres,grant_user_1=a/postgres}")
|
||||
57637 | (grant_on_table.ref_table,test_a,"{grant_user_0=a/postgres,grant_user_1=a/postgres}")
|
||||
57638 | (grant_on_table.ref_table,test_a,"{grant_user_0=a/postgres,grant_user_1=a/postgres}")
|
||||
57636 | (grant_on_table.ref_table,test_mix,"{grant_user_0=w/postgres,grant_user_1=w/postgres}")
|
||||
57637 | (grant_on_table.ref_table,test_mix,"{grant_user_0=w/postgres,grant_user_1=w/postgres}")
|
||||
57638 | (grant_on_table.ref_table,test_mix,"{grant_user_0=w/postgres,grant_user_1=w/postgres}")
|
||||
57636 | (grant_on_table.ref_table,test_w,"{grant_user_0=w/postgres,grant_user_1=w/postgres}")
|
||||
57637 | (grant_on_table.ref_table,test_w,"{grant_user_0=w/postgres,grant_user_1=w/postgres}")
|
||||
57638 | (grant_on_table.ref_table,test_w,"{grant_user_0=w/postgres,grant_user_1=w/postgres}")
|
||||
(24 rows)
|
||||
|
||||
-- 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 ;
|
||||
nodeport | unnest
|
||||
---------------------------------------------------------------------
|
||||
57636 | (dist_table,)
|
||||
57637 | (dist_table,)
|
||||
57638 | (dist_table,)
|
||||
57636 | (local_table,)
|
||||
57637 | (local_table,)
|
||||
57638 | (local_table,)
|
||||
57636 | (ref_table,{postgres=arwdDxtm/postgres})
|
||||
57637 | (ref_table,{postgres=arwdDxtm/postgres})
|
||||
57638 | (ref_table,{postgres=arwdDxtm/postgres})
|
||||
(9 rows)
|
||||
|
||||
:verify_grant_attributes ;
|
||||
nodeport | unnest
|
||||
---------------------------------------------------------------------
|
||||
(0 rows)
|
||||
|
||||
--
|
||||
-- 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;
|
||||
ERROR: permission denied for table 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;
|
||||
test_r | test_mix
|
||||
---------------------------------------------------------------------
|
||||
| 2
|
||||
(1 row)
|
||||
|
||||
-- granted:
|
||||
DELETE FROM ref_table;
|
||||
-- not granted:
|
||||
SELECT test_a FROM ref_table;
|
||||
ERROR: permission denied for table ref_table
|
||||
-- not granted:
|
||||
UPDATE ref_table SET null_privs = 3;
|
||||
ERROR: permission denied for table ref_table
|
||||
RESET ROLE;
|
||||
-- check on coordinator and workers
|
||||
:verify_grant_table ;
|
||||
nodeport | unnest
|
||||
---------------------------------------------------------------------
|
||||
57636 | (dist_table,)
|
||||
57637 | (dist_table,)
|
||||
57638 | (dist_table,)
|
||||
57636 | (local_table,)
|
||||
57637 | (local_table,)
|
||||
57638 | (local_table,)
|
||||
57636 | (ref_table,"{postgres=arwdDxtm/postgres,grant_user_0=d/postgres,grant_user_1=d/postgres}")
|
||||
57637 | (ref_table,"{postgres=arwdDxtm/postgres,grant_user_0=d/postgres,grant_user_1=d/postgres}")
|
||||
57638 | (ref_table,"{postgres=arwdDxtm/postgres,grant_user_0=d/postgres,grant_user_1=d/postgres}")
|
||||
(9 rows)
|
||||
|
||||
:verify_grant_attributes ;
|
||||
nodeport | unnest
|
||||
---------------------------------------------------------------------
|
||||
57636 | (grant_on_table.ref_table,test_mix,"{grant_user_0=r/postgres,grant_user_1=r/postgres}")
|
||||
57637 | (grant_on_table.ref_table,test_mix,"{grant_user_0=r/postgres,grant_user_1=r/postgres}")
|
||||
57638 | (grant_on_table.ref_table,test_mix,"{grant_user_0=r/postgres,grant_user_1=r/postgres}")
|
||||
57636 | (grant_on_table.ref_table,test_r,"{grant_user_0=r/postgres,grant_user_1=r/postgres}")
|
||||
57637 | (grant_on_table.ref_table,test_r,"{grant_user_0=r/postgres,grant_user_1=r/postgres}")
|
||||
57638 | (grant_on_table.ref_table,test_r,"{grant_user_0=r/postgres,grant_user_1=r/postgres}")
|
||||
(6 rows)
|
||||
|
||||
-- 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 ;
|
||||
nodeport | unnest
|
||||
---------------------------------------------------------------------
|
||||
57636 | (dist_table,)
|
||||
57637 | (dist_table,)
|
||||
57638 | (dist_table,)
|
||||
57636 | (local_table,)
|
||||
57637 | (local_table,)
|
||||
57638 | (local_table,)
|
||||
57636 | (ref_table,{postgres=arwdDxtm/postgres})
|
||||
57637 | (ref_table,{postgres=arwdDxtm/postgres})
|
||||
57638 | (ref_table,{postgres=arwdDxtm/postgres})
|
||||
(9 rows)
|
||||
|
||||
:verify_grant_attributes ;
|
||||
nodeport | unnest
|
||||
---------------------------------------------------------------------
|
||||
(0 rows)
|
||||
|
||||
--
|
||||
-- check we also propagate system columns
|
||||
-- we use only SELECT
|
||||
--
|
||||
SET ROLE grant_user_0;
|
||||
-- not granted yet:
|
||||
SELECT ctid, xmin FROM ref_table;
|
||||
ERROR: permission denied for table 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;
|
||||
ctid | xmin
|
||||
---------------------------------------------------------------------
|
||||
(0 rows)
|
||||
|
||||
-- not granted:
|
||||
SELECT ctid, test_a FROM ref_table;
|
||||
ERROR: permission denied for table ref_table
|
||||
RESET ROLE;
|
||||
-- check on coordinator and workers
|
||||
:verify_grant_table ;
|
||||
nodeport | unnest
|
||||
---------------------------------------------------------------------
|
||||
57636 | (dist_table,)
|
||||
57637 | (dist_table,)
|
||||
57638 | (dist_table,)
|
||||
57636 | (local_table,)
|
||||
57637 | (local_table,)
|
||||
57638 | (local_table,)
|
||||
57636 | (ref_table,{postgres=arwdDxtm/postgres})
|
||||
57637 | (ref_table,{postgres=arwdDxtm/postgres})
|
||||
57638 | (ref_table,{postgres=arwdDxtm/postgres})
|
||||
(9 rows)
|
||||
|
||||
:verify_grant_attributes ;
|
||||
nodeport | unnest
|
||||
---------------------------------------------------------------------
|
||||
57636 | (grant_on_table.ref_table,ctid,{grant_user_0=r/postgres})
|
||||
57637 | (grant_on_table.ref_table,ctid,{grant_user_0=r/postgres})
|
||||
57638 | (grant_on_table.ref_table,ctid,{grant_user_0=r/postgres})
|
||||
57636 | (grant_on_table.ref_table,xmin,{grant_user_0=r/postgres})
|
||||
57637 | (grant_on_table.ref_table,xmin,{grant_user_0=r/postgres})
|
||||
57638 | (grant_on_table.ref_table,xmin,{grant_user_0=r/postgres})
|
||||
(6 rows)
|
||||
|
||||
-- cleanup
|
||||
REVOKE SELECT (ctid, xmin) ON ref_table FROM grant_user_0;
|
||||
-- check on coordinator and workers
|
||||
:verify_grant_table ;
|
||||
nodeport | unnest
|
||||
---------------------------------------------------------------------
|
||||
57636 | (dist_table,)
|
||||
57637 | (dist_table,)
|
||||
57638 | (dist_table,)
|
||||
57636 | (local_table,)
|
||||
57637 | (local_table,)
|
||||
57638 | (local_table,)
|
||||
57636 | (ref_table,{postgres=arwdDxtm/postgres})
|
||||
57637 | (ref_table,{postgres=arwdDxtm/postgres})
|
||||
57638 | (ref_table,{postgres=arwdDxtm/postgres})
|
||||
(9 rows)
|
||||
|
||||
:verify_grant_attributes ;
|
||||
nodeport | unnest
|
||||
---------------------------------------------------------------------
|
||||
(0 rows)
|
||||
|
||||
--
|
||||
-- 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);
|
||||
ERROR: permission denied for table ref_table
|
||||
SET ROLE grant_user_1;
|
||||
-- not granted yet:
|
||||
INSERT INTO ref_table (id, test_mix) VALUES (9, 3);
|
||||
ERROR: permission denied for table ref_table
|
||||
RESET ROLE;
|
||||
GRANT ALL (id) ON ref_table TO grant_user_0;
|
||||
GRANT ALL (id, test_mix) ON ref_table TO grant_user_1;
|
||||
-- ALL cannot be mixed with other privs
|
||||
-- should error:
|
||||
GRANT SELECT (null_privs), ALL (null_privs) ON ref_table TO nogrant_user;
|
||||
ERROR: syntax error at or near "ALL"
|
||||
-- should error:
|
||||
GRANT ALL (null_privs), SELECT (null_privs) ON ref_table TO nogrant_user;
|
||||
ERROR: syntax error at or near ","
|
||||
SET ROLE grant_user_0;
|
||||
-- granted:
|
||||
INSERT INTO ref_table (id) VALUES (13);
|
||||
SET ROLE grant_user_1;
|
||||
-- granted:
|
||||
INSERT INTO ref_table (id, test_mix) VALUES (9, 3);
|
||||
-- not granted:
|
||||
INSERT INTO ref_table (null_privs) VALUES (3);
|
||||
ERROR: permission denied for table ref_table
|
||||
-- granted:
|
||||
SELECT id, test_mix FROM ref_table;
|
||||
id | test_mix
|
||||
---------------------------------------------------------------------
|
||||
13 |
|
||||
9 | 3
|
||||
(2 rows)
|
||||
|
||||
-- not granted:
|
||||
SELECT null_privs FROM ref_table;
|
||||
ERROR: permission denied for table ref_table
|
||||
-- not granted:
|
||||
DELETE FROM ref_table;
|
||||
ERROR: permission denied for table ref_table
|
||||
RESET ROLE;
|
||||
-- check on coordinator and workers
|
||||
:verify_grant_table ;
|
||||
nodeport | unnest
|
||||
---------------------------------------------------------------------
|
||||
57636 | (dist_table,)
|
||||
57637 | (dist_table,)
|
||||
57638 | (dist_table,)
|
||||
57636 | (local_table,)
|
||||
57637 | (local_table,)
|
||||
57638 | (local_table,)
|
||||
57636 | (ref_table,{postgres=arwdDxtm/postgres})
|
||||
57637 | (ref_table,{postgres=arwdDxtm/postgres})
|
||||
57638 | (ref_table,{postgres=arwdDxtm/postgres})
|
||||
(9 rows)
|
||||
|
||||
:verify_grant_attributes ;
|
||||
nodeport | unnest
|
||||
---------------------------------------------------------------------
|
||||
57636 | (grant_on_table.ref_table,id,"{grant_user_0=arwx/postgres,grant_user_1=arwx/postgres}")
|
||||
57637 | (grant_on_table.ref_table,id,"{grant_user_0=arwx/postgres,grant_user_1=arwx/postgres}")
|
||||
57638 | (grant_on_table.ref_table,id,"{grant_user_0=arwx/postgres,grant_user_1=arwx/postgres}")
|
||||
57636 | (grant_on_table.ref_table,test_mix,{grant_user_1=arwx/postgres})
|
||||
57637 | (grant_on_table.ref_table,test_mix,{grant_user_1=arwx/postgres})
|
||||
57638 | (grant_on_table.ref_table,test_mix,{grant_user_1=arwx/postgres})
|
||||
(6 rows)
|
||||
|
||||
-- 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 ;
|
||||
nodeport | unnest
|
||||
---------------------------------------------------------------------
|
||||
57636 | (dist_table,)
|
||||
57637 | (dist_table,)
|
||||
57638 | (dist_table,)
|
||||
57636 | (local_table,)
|
||||
57637 | (local_table,)
|
||||
57638 | (local_table,)
|
||||
57636 | (ref_table,{postgres=arwdDxtm/postgres})
|
||||
57637 | (ref_table,{postgres=arwdDxtm/postgres})
|
||||
57638 | (ref_table,{postgres=arwdDxtm/postgres})
|
||||
(9 rows)
|
||||
|
||||
:verify_grant_attributes ;
|
||||
nodeport | unnest
|
||||
---------------------------------------------------------------------
|
||||
(0 rows)
|
||||
|
||||
--
|
||||
-- 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;
|
||||
ERROR: permission denied for table ref_table
|
||||
RESET ROLE;
|
||||
-- NOTE:
|
||||
-- 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_0;
|
||||
-- check non propagation for local table (we'll just check ACL later, no INSERT testing)
|
||||
GRANT INSERT (test_mix) ON local_table TO grant_user_0;
|
||||
-- check we can propagate also when mixed with distributed table:
|
||||
GRANT SELECT (test_r, test_mix) ON local_table, dist_table TO grant_user_1;
|
||||
SET ROLE grant_user_0;
|
||||
-- granted:
|
||||
SELECT id FROM ref_table
|
||||
UNION ALL SELECT id FROM dist_table
|
||||
UNION ALL SELECT id FROM local_table;
|
||||
id
|
||||
---------------------------------------------------------------------
|
||||
1
|
||||
(1 row)
|
||||
|
||||
SET ROLE grant_user_1;
|
||||
-- granted:
|
||||
SELECT test_r, test_mix FROM dist_table
|
||||
UNION ALL SELECT test_r, test_mix FROM local_table;
|
||||
test_r | test_mix
|
||||
---------------------------------------------------------------------
|
||||
| 3
|
||||
(1 row)
|
||||
|
||||
RESET ROLE;
|
||||
-- check on coordinator and workers
|
||||
-- we pay special attention to local_table privileges here:
|
||||
:verify_grant_table ;
|
||||
nodeport | unnest
|
||||
---------------------------------------------------------------------
|
||||
57636 | (dist_table,)
|
||||
57637 | (dist_table,)
|
||||
57638 | (dist_table,)
|
||||
57636 | (local_table,)
|
||||
57637 | (local_table,)
|
||||
57638 | (local_table,)
|
||||
57636 | (ref_table,{postgres=arwdDxtm/postgres})
|
||||
57637 | (ref_table,{postgres=arwdDxtm/postgres})
|
||||
57638 | (ref_table,{postgres=arwdDxtm/postgres})
|
||||
(9 rows)
|
||||
|
||||
:verify_grant_attributes ;
|
||||
nodeport | unnest
|
||||
---------------------------------------------------------------------
|
||||
57636 | (grant_on_table.dist_table,id,{grant_user_0=r/postgres})
|
||||
57637 | (grant_on_table.dist_table,id,{grant_user_0=r/postgres})
|
||||
57638 | (grant_on_table.dist_table,id,{grant_user_0=r/postgres})
|
||||
57636 | (grant_on_table.dist_table,test_mix,{grant_user_1=r/postgres})
|
||||
57637 | (grant_on_table.dist_table,test_mix,{grant_user_1=r/postgres})
|
||||
57638 | (grant_on_table.dist_table,test_mix,{grant_user_1=r/postgres})
|
||||
57636 | (grant_on_table.dist_table,test_r,{grant_user_1=r/postgres})
|
||||
57637 | (grant_on_table.dist_table,test_r,{grant_user_1=r/postgres})
|
||||
57638 | (grant_on_table.dist_table,test_r,{grant_user_1=r/postgres})
|
||||
57636 | (grant_on_table.local_table,id,{grant_user_0=r/postgres})
|
||||
57636 | (grant_on_table.local_table,test_mix,"{grant_user_0=a/postgres,grant_user_1=r/postgres}")
|
||||
57636 | (grant_on_table.local_table,test_r,{grant_user_1=r/postgres})
|
||||
57636 | (grant_on_table.ref_table,id,{grant_user_0=r/postgres})
|
||||
57637 | (grant_on_table.ref_table,id,{grant_user_0=r/postgres})
|
||||
57638 | (grant_on_table.ref_table,id,{grant_user_0=r/postgres})
|
||||
(15 rows)
|
||||
|
||||
-- cleanup
|
||||
REVOKE SELECT (id) ON ALL TABLES IN SCHEMA grant_on_table FROM grant_user_0;
|
||||
-- check non propagation for local table (we'll just check ACL later, no INSERT testing)
|
||||
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 ;
|
||||
nodeport | unnest
|
||||
---------------------------------------------------------------------
|
||||
57636 | (dist_table,)
|
||||
57637 | (dist_table,)
|
||||
57638 | (dist_table,)
|
||||
57636 | (local_table,)
|
||||
57637 | (local_table,)
|
||||
57638 | (local_table,)
|
||||
57636 | (ref_table,{postgres=arwdDxtm/postgres})
|
||||
57637 | (ref_table,{postgres=arwdDxtm/postgres})
|
||||
57638 | (ref_table,{postgres=arwdDxtm/postgres})
|
||||
(9 rows)
|
||||
|
||||
:verify_grant_attributes ;
|
||||
nodeport | unnest
|
||||
---------------------------------------------------------------------
|
||||
(0 rows)
|
||||
|
||||
--
|
||||
-- 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;
|
||||
-- not granted yet:
|
||||
SELECT test_r FROM ref_table;
|
||||
ERROR: permission denied for table ref_table
|
||||
RESET ROLE;
|
||||
GRANT TRUNCATE (null_privs), SELECT (null_privs) ON ref_table TO nogrant_user;
|
||||
ERROR: invalid privilege type TRUNCATE for column
|
||||
SET ROLE grant_user_0;
|
||||
-- still not granted:
|
||||
SELECT test_r FROM ref_table;
|
||||
ERROR: permission denied for table ref_table
|
||||
-- still not granted:
|
||||
TRUNCATE ref_table;
|
||||
ERROR: permission denied for table ref_table
|
||||
RESET ROLE;
|
||||
-- check on coordinator and workers
|
||||
:verify_grant_table ;
|
||||
nodeport | unnest
|
||||
---------------------------------------------------------------------
|
||||
57636 | (dist_table,)
|
||||
57637 | (dist_table,)
|
||||
57638 | (dist_table,)
|
||||
57636 | (local_table,)
|
||||
57637 | (local_table,)
|
||||
57638 | (local_table,)
|
||||
57636 | (ref_table,{postgres=arwdDxtm/postgres})
|
||||
57637 | (ref_table,{postgres=arwdDxtm/postgres})
|
||||
57638 | (ref_table,{postgres=arwdDxtm/postgres})
|
||||
(9 rows)
|
||||
|
||||
:verify_grant_attributes ;
|
||||
nodeport | unnest
|
||||
---------------------------------------------------------------------
|
||||
(0 rows)
|
||||
|
||||
-- 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;
|
||||
ERROR: operation is not allowed on this node
|
||||
HINT: Connect to the coordinator and run it again.
|
||||
\c - - - :master_port
|
||||
SET search_path TO grant_on_table;
|
||||
-- check on coordinator and workers
|
||||
:verify_grant_table ;
|
||||
nodeport | unnest
|
||||
---------------------------------------------------------------------
|
||||
57636 | (dist_table,)
|
||||
57637 | (dist_table,)
|
||||
57638 | (dist_table,)
|
||||
57636 | (local_table,)
|
||||
57637 | (local_table,)
|
||||
57638 | (local_table,)
|
||||
57636 | (ref_table,{postgres=arwdDxtm/postgres})
|
||||
57637 | (ref_table,{postgres=arwdDxtm/postgres})
|
||||
57638 | (ref_table,{postgres=arwdDxtm/postgres})
|
||||
(9 rows)
|
||||
|
||||
:verify_grant_attributes ;
|
||||
nodeport | unnest
|
||||
---------------------------------------------------------------------
|
||||
(0 rows)
|
||||
|
||||
-- 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;
|
||||
ERROR: permission denied for table ref_table
|
||||
SET ROLE grant_user_1;
|
||||
-- not granted yet:
|
||||
SELECT test_r, test_mix FROM ref_table;
|
||||
ERROR: permission denied for table 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;
|
||||
test_r | test_mix
|
||||
---------------------------------------------------------------------
|
||||
(0 rows)
|
||||
|
||||
RESET ROLE;
|
||||
-- check on coordinator and workers
|
||||
:verify_grant_table ;
|
||||
nodeport | unnest
|
||||
---------------------------------------------------------------------
|
||||
57636 | (dist_table,)
|
||||
57637 | (dist_table,)
|
||||
57638 | (dist_table,)
|
||||
57636 | (local_table,)
|
||||
57637 | (local_table,)
|
||||
57638 | (local_table,)
|
||||
57636 | (ref_table,{postgres=arwdDxtm/postgres})
|
||||
57637 | (ref_table,{postgres=arwdDxtm/postgres})
|
||||
57638 | (ref_table,{postgres=arwdDxtm/postgres})
|
||||
(9 rows)
|
||||
|
||||
:verify_grant_attributes ;
|
||||
nodeport | unnest
|
||||
---------------------------------------------------------------------
|
||||
57636 | (grant_on_table.ref_table,test_mix,"{grant_user_0=r*/postgres,grant_user_1=r/grant_user_0}")
|
||||
57637 | (grant_on_table.ref_table,test_mix,"{grant_user_0=r*/postgres,grant_user_1=r/grant_user_0}")
|
||||
57638 | (grant_on_table.ref_table,test_mix,"{grant_user_0=r*/postgres,grant_user_1=r/grant_user_0}")
|
||||
57636 | (grant_on_table.ref_table,test_r,"{grant_user_0=r*/postgres,grant_user_1=r/grant_user_0}")
|
||||
57637 | (grant_on_table.ref_table,test_r,"{grant_user_0=r*/postgres,grant_user_1=r/grant_user_0}")
|
||||
57638 | (grant_on_table.ref_table,test_r,"{grant_user_0=r*/postgres,grant_user_1=r/grant_user_0}")
|
||||
(6 rows)
|
||||
|
||||
-- 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 ;
|
||||
nodeport | unnest
|
||||
---------------------------------------------------------------------
|
||||
57636 | (dist_table,)
|
||||
57637 | (dist_table,)
|
||||
57638 | (dist_table,)
|
||||
57636 | (local_table,)
|
||||
57637 | (local_table,)
|
||||
57638 | (local_table,)
|
||||
57636 | (ref_table,{postgres=arwdDxtm/postgres})
|
||||
57637 | (ref_table,{postgres=arwdDxtm/postgres})
|
||||
57638 | (ref_table,{postgres=arwdDxtm/postgres})
|
||||
(9 rows)
|
||||
|
||||
:verify_grant_attributes ;
|
||||
nodeport | unnest
|
||||
---------------------------------------------------------------------
|
||||
57636 | (grant_on_table.ref_table,test_mix,{grant_user_0=r*/postgres})
|
||||
57637 | (grant_on_table.ref_table,test_mix,{grant_user_0=r*/postgres})
|
||||
57638 | (grant_on_table.ref_table,test_mix,{grant_user_0=r*/postgres})
|
||||
57636 | (grant_on_table.ref_table,test_r,{grant_user_0=r*/postgres})
|
||||
57637 | (grant_on_table.ref_table,test_r,{grant_user_0=r*/postgres})
|
||||
57638 | (grant_on_table.ref_table,test_r,{grant_user_0=r*/postgres})
|
||||
(6 rows)
|
||||
|
||||
-- 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 ;
|
||||
nodeport | unnest
|
||||
---------------------------------------------------------------------
|
||||
57636 | (dist_table,)
|
||||
57637 | (dist_table,)
|
||||
57638 | (dist_table,)
|
||||
57636 | (local_table,)
|
||||
57637 | (local_table,)
|
||||
57638 | (local_table,)
|
||||
57636 | (ref_table,{postgres=arwdDxtm/postgres})
|
||||
57637 | (ref_table,{postgres=arwdDxtm/postgres})
|
||||
57638 | (ref_table,{postgres=arwdDxtm/postgres})
|
||||
(9 rows)
|
||||
|
||||
:verify_grant_attributes ;
|
||||
nodeport | unnest
|
||||
---------------------------------------------------------------------
|
||||
57636 | (grant_on_table.ref_table,test_mix,{grant_user_0=r/postgres})
|
||||
57637 | (grant_on_table.ref_table,test_mix,{grant_user_0=r/postgres})
|
||||
57638 | (grant_on_table.ref_table,test_mix,{grant_user_0=r/postgres})
|
||||
57636 | (grant_on_table.ref_table,test_r,{grant_user_0=r/postgres})
|
||||
57637 | (grant_on_table.ref_table,test_r,{grant_user_0=r/postgres})
|
||||
57638 | (grant_on_table.ref_table,test_r,{grant_user_0=r/postgres})
|
||||
(6 rows)
|
||||
|
||||
-- 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 ;
|
||||
nodeport | unnest
|
||||
---------------------------------------------------------------------
|
||||
57636 | (dist_table,)
|
||||
57637 | (dist_table,)
|
||||
57638 | (dist_table,)
|
||||
57636 | (local_table,)
|
||||
57637 | (local_table,)
|
||||
57638 | (local_table,)
|
||||
57636 | (ref_table,{postgres=arwdDxtm/postgres})
|
||||
57637 | (ref_table,{postgres=arwdDxtm/postgres})
|
||||
57638 | (ref_table,{postgres=arwdDxtm/postgres})
|
||||
(9 rows)
|
||||
|
||||
:verify_grant_attributes ;
|
||||
nodeport | unnest
|
||||
---------------------------------------------------------------------
|
||||
(0 rows)
|
||||
|
||||
-- prevent useless messages on DROP objects.
|
||||
SET client_min_messages TO ERROR;
|
||||
DROP TABLE dist_table, ref_table;
|
||||
SELECT result FROM run_command_on_all_nodes('DROP TABLE grant_on_table.local_table');
|
||||
result
|
||||
---------------------------------------------------------------------
|
||||
DROP TABLE
|
||||
DROP TABLE
|
||||
DROP TABLE
|
||||
(3 rows)
|
||||
|
||||
RESET client_min_messages;
|
||||
--
|
||||
-- check we propagate privileges when GRANTed before distributed and when adding a node
|
||||
-- we use only SELECT
|
||||
--
|
||||
-- test propagation on columns when distributing the table after GRANT has been executed
|
||||
CREATE TABLE grant_table_propagated (id int primary key);
|
||||
GRANT SELECT (id) ON grant_table_propagated TO grant_user_0;
|
||||
SELECT create_distributed_table('grant_table_propagated', 'id');
|
||||
create_distributed_table
|
||||
---------------------------------------------------------------------
|
||||
|
||||
(1 row)
|
||||
|
||||
SET ROLE grant_user_0;
|
||||
-- granted:
|
||||
SELECT id FROM grant_table_propagated;
|
||||
id
|
||||
---------------------------------------------------------------------
|
||||
(0 rows)
|
||||
|
||||
RESET ROLE;
|
||||
-- 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'') $$) 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''::regclass) AND attacl IS NOT NULL $$) join pg_dist_node using (nodeid) ORDER BY 2, 1'
|
||||
:verify_grant_table ;
|
||||
nodeport | unnest
|
||||
---------------------------------------------------------------------
|
||||
57636 | (grant_table_propagated,)
|
||||
57637 | (grant_table_propagated,)
|
||||
57638 | (grant_table_propagated,)
|
||||
(3 rows)
|
||||
|
||||
:verify_grant_attributes ;
|
||||
nodeport | unnest
|
||||
---------------------------------------------------------------------
|
||||
57636 | (grant_on_table.grant_table_propagated,id,{grant_user_0=r/postgres})
|
||||
57637 | (grant_on_table.grant_table_propagated,id,{grant_user_0=r/postgres})
|
||||
57638 | (grant_on_table.grant_table_propagated,id,{grant_user_0=r/postgres})
|
||||
(3 rows)
|
||||
|
||||
-- cleanup
|
||||
REVOKE SELECT (id) ON grant_table_propagated FROM grant_user_0;
|
||||
:verify_grant_table ;
|
||||
nodeport | unnest
|
||||
---------------------------------------------------------------------
|
||||
57636 | (grant_table_propagated,)
|
||||
57637 | (grant_table_propagated,)
|
||||
57638 | (grant_table_propagated,)
|
||||
(3 rows)
|
||||
|
||||
:verify_grant_attributes ;
|
||||
nodeport | unnest
|
||||
---------------------------------------------------------------------
|
||||
(0 rows)
|
||||
|
||||
-- prevent useless messages on DROP objects.
|
||||
SET client_min_messages TO ERROR;
|
||||
DROP TABLE grant_table_propagated;
|
||||
RESET client_min_messages;
|
||||
-- similar test but adding a node after the fact
|
||||
-- remove one of the worker nodes:
|
||||
SELECT citus_remove_node('localhost', :worker_2_port);
|
||||
citus_remove_node
|
||||
---------------------------------------------------------------------
|
||||
|
||||
(1 row)
|
||||
|
||||
CREATE TABLE grant_table_propagated_after (id int primary key);
|
||||
SET citus.shard_replication_factor TO 1;
|
||||
SELECT create_distributed_table('grant_table_propagated_after', 'id');
|
||||
create_distributed_table
|
||||
---------------------------------------------------------------------
|
||||
|
||||
(1 row)
|
||||
|
||||
SET citus.shard_replication_factor TO 2;
|
||||
GRANT SELECT (id) ON grant_table_propagated_after TO grant_user_0;
|
||||
-- add back the worker node
|
||||
SELECT FROM citus_add_node('localhost', :worker_2_port);
|
||||
--
|
||||
(1 row)
|
||||
|
||||
-- granted:
|
||||
SELECT id FROM grant_table_propagated_after;
|
||||
id
|
||||
---------------------------------------------------------------------
|
||||
(0 rows)
|
||||
|
||||
-- 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 ;
|
||||
nodeport | unnest
|
||||
---------------------------------------------------------------------
|
||||
57636 | (grant_table_propagated_after,)
|
||||
57637 | (grant_table_propagated_after,)
|
||||
57638 | (grant_table_propagated_after,)
|
||||
(3 rows)
|
||||
|
||||
:verify_grant_attributes ;
|
||||
nodeport | unnest
|
||||
---------------------------------------------------------------------
|
||||
57636 | (grant_on_table.grant_table_propagated_after,id,{grant_user_0=r/postgres})
|
||||
57637 | (grant_on_table.grant_table_propagated_after,id,{grant_user_0=r/postgres})
|
||||
57638 | (grant_on_table.grant_table_propagated_after,id,{grant_user_0=r/postgres})
|
||||
(3 rows)
|
||||
|
||||
-- cleanup
|
||||
REVOKE SELECT (id) ON grant_table_propagated_after FROM grant_user_0;
|
||||
:verify_grant_table ;
|
||||
nodeport | unnest
|
||||
---------------------------------------------------------------------
|
||||
57636 | (grant_table_propagated_after,)
|
||||
57637 | (grant_table_propagated_after,)
|
||||
57638 | (grant_table_propagated_after,)
|
||||
(3 rows)
|
||||
|
||||
:verify_grant_attributes ;
|
||||
nodeport | unnest
|
||||
---------------------------------------------------------------------
|
||||
(0 rows)
|
||||
|
||||
-- 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.
|
||||
SET client_min_messages TO ERROR;
|
||||
DROP SCHEMA grant_on_table CASCADE;
|
||||
DROP ROLE grant_user_0, grant_user_1;
|
||||
RESET client_min_messages;
|
||||
RESET search_path;
|
|
@ -0,0 +1,930 @@
|
|||
-- PostgreSQL 17 introduces MAINTAIN privilege, this change the default output
|
||||
-- of some test queries.
|
||||
--
|
||||
-- Alternative "grant_on_table_propagation_0.out" and this comment can be
|
||||
-- removed when support for PostgreSQL versions < 17 is dropped.
|
||||
SHOW server_version \gset
|
||||
SELECT substring(:'server_version', '\d+')::int >= 17 AS server_version_ge_17;
|
||||
server_version_ge_17
|
||||
---------------------------------------------------------------------
|
||||
f
|
||||
(1 row)
|
||||
|
||||
--
|
||||
-- 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 on all nodes and 2 managed by citus
|
||||
-- null_privs ACL must not be updated in anyway.
|
||||
CREATE TABLE dist_table (id bigint GENERATED BY DEFAULT AS IDENTITY primary key
|
||||
, test_a int -- test for INSERT
|
||||
, test_r text -- test for SELECT
|
||||
, test_w text -- test for UPDATE
|
||||
, test_mix int -- test for ALL/mixed
|
||||
, null_privs text
|
||||
);
|
||||
SELECT create_distributed_table('dist_table', 'id');
|
||||
create_distributed_table
|
||||
---------------------------------------------------------------------
|
||||
|
||||
(1 row)
|
||||
|
||||
CREATE TABLE ref_table (id bigint GENERATED BY DEFAULT AS IDENTITY primary key
|
||||
, test_a int -- test for INSERT
|
||||
, test_r text -- test for SELECT
|
||||
, test_w text -- test for UPDATE
|
||||
, test_mix int -- test for ALL
|
||||
, null_privs text
|
||||
);
|
||||
SELECT create_reference_table('ref_table');
|
||||
create_reference_table
|
||||
---------------------------------------------------------------------
|
||||
|
||||
(1 row)
|
||||
|
||||
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)');
|
||||
result
|
||||
---------------------------------------------------------------------
|
||||
CREATE TABLE
|
||||
CREATE TABLE
|
||||
CREATE TABLE
|
||||
(3 rows)
|
||||
|
||||
-- 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 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
|
||||
--
|
||||
--
|
||||
-- when executing a table level grant, "postgres" is add/listed in pg_class.relacl
|
||||
-- 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;
|
||||
-- not granted yet:
|
||||
SELECT test_r FROM ref_table;
|
||||
ERROR: permission denied for table ref_table
|
||||
RESET ROLE;
|
||||
GRANT SELECT (test_r) ON ref_table TO grant_user_0;
|
||||
SET ROLE grant_user_0;
|
||||
-- granted:
|
||||
SELECT test_r FROM ref_table;
|
||||
test_r
|
||||
---------------------------------------------------------------------
|
||||
(0 rows)
|
||||
|
||||
-- not granted:
|
||||
SELECT test_a FROM ref_table;
|
||||
ERROR: permission denied for table ref_table
|
||||
SET ROLE grant_user_1;
|
||||
-- not granted:
|
||||
SELECT test_r FROM ref_table;
|
||||
ERROR: permission denied for table ref_table
|
||||
RESET ROLE;
|
||||
-- check on coordinator and workers
|
||||
:verify_grant_table ;
|
||||
nodeport | unnest
|
||||
---------------------------------------------------------------------
|
||||
57636 | (dist_table,)
|
||||
57637 | (dist_table,)
|
||||
57638 | (dist_table,)
|
||||
57636 | (local_table,)
|
||||
57637 | (local_table,)
|
||||
57638 | (local_table,)
|
||||
57636 | (ref_table,{postgres=arwdDxt/postgres})
|
||||
57637 | (ref_table,{postgres=arwdDxt/postgres})
|
||||
57638 | (ref_table,{postgres=arwdDxt/postgres})
|
||||
(9 rows)
|
||||
|
||||
:verify_grant_attributes ;
|
||||
nodeport | unnest
|
||||
---------------------------------------------------------------------
|
||||
57636 | (grant_on_table.ref_table,test_r,{grant_user_0=r/postgres})
|
||||
57637 | (grant_on_table.ref_table,test_r,{grant_user_0=r/postgres})
|
||||
57638 | (grant_on_table.ref_table,test_r,{grant_user_0=r/postgres})
|
||||
(3 rows)
|
||||
|
||||
-- cleanup
|
||||
REVOKE SELECT (test_r) ON ref_table FROM grant_user_0;
|
||||
-- check on coordinator and workers
|
||||
:verify_grant_table ;
|
||||
nodeport | unnest
|
||||
---------------------------------------------------------------------
|
||||
57636 | (dist_table,)
|
||||
57637 | (dist_table,)
|
||||
57638 | (dist_table,)
|
||||
57636 | (local_table,)
|
||||
57637 | (local_table,)
|
||||
57638 | (local_table,)
|
||||
57636 | (ref_table,{postgres=arwdDxt/postgres})
|
||||
57637 | (ref_table,{postgres=arwdDxt/postgres})
|
||||
57638 | (ref_table,{postgres=arwdDxt/postgres})
|
||||
(9 rows)
|
||||
|
||||
:verify_grant_attributes ;
|
||||
nodeport | unnest
|
||||
---------------------------------------------------------------------
|
||||
(0 rows)
|
||||
|
||||
--
|
||||
-- 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;
|
||||
-- not granted yet:
|
||||
INSERT INTO ref_table (test_a) VALUES (1);
|
||||
ERROR: permission denied for table ref_table
|
||||
RESET ROLE;
|
||||
-- we would prefer not have to grant INSERT (id) as expected in the standard but
|
||||
-- Citus rewrite queries with such attributes, which prevent standard to be applied.
|
||||
GRANT INSERT (id, test_a), UPDATE (test_w, test_mix) ON ref_table, dist_table TO grant_user_0, grant_user_1;
|
||||
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);
|
||||
ERROR: permission denied for table ref_table
|
||||
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;
|
||||
-- check on coordinator and workers
|
||||
:verify_grant_table ;
|
||||
nodeport | unnest
|
||||
---------------------------------------------------------------------
|
||||
57636 | (dist_table,)
|
||||
57637 | (dist_table,)
|
||||
57638 | (dist_table,)
|
||||
57636 | (local_table,)
|
||||
57637 | (local_table,)
|
||||
57638 | (local_table,)
|
||||
57636 | (ref_table,{postgres=arwdDxt/postgres})
|
||||
57637 | (ref_table,{postgres=arwdDxt/postgres})
|
||||
57638 | (ref_table,{postgres=arwdDxt/postgres})
|
||||
(9 rows)
|
||||
|
||||
:verify_grant_attributes ;
|
||||
nodeport | unnest
|
||||
---------------------------------------------------------------------
|
||||
57636 | (grant_on_table.dist_table,id,"{grant_user_0=a/postgres,grant_user_1=a/postgres}")
|
||||
57637 | (grant_on_table.dist_table,id,"{grant_user_0=a/postgres,grant_user_1=a/postgres}")
|
||||
57638 | (grant_on_table.dist_table,id,"{grant_user_0=a/postgres,grant_user_1=a/postgres}")
|
||||
57636 | (grant_on_table.dist_table,test_a,"{grant_user_0=a/postgres,grant_user_1=a/postgres}")
|
||||
57637 | (grant_on_table.dist_table,test_a,"{grant_user_0=a/postgres,grant_user_1=a/postgres}")
|
||||
57638 | (grant_on_table.dist_table,test_a,"{grant_user_0=a/postgres,grant_user_1=a/postgres}")
|
||||
57636 | (grant_on_table.dist_table,test_mix,"{grant_user_0=w/postgres,grant_user_1=w/postgres}")
|
||||
57637 | (grant_on_table.dist_table,test_mix,"{grant_user_0=w/postgres,grant_user_1=w/postgres}")
|
||||
57638 | (grant_on_table.dist_table,test_mix,"{grant_user_0=w/postgres,grant_user_1=w/postgres}")
|
||||
57636 | (grant_on_table.dist_table,test_w,"{grant_user_0=w/postgres,grant_user_1=w/postgres}")
|
||||
57637 | (grant_on_table.dist_table,test_w,"{grant_user_0=w/postgres,grant_user_1=w/postgres}")
|
||||
57638 | (grant_on_table.dist_table,test_w,"{grant_user_0=w/postgres,grant_user_1=w/postgres}")
|
||||
57636 | (grant_on_table.ref_table,id,"{grant_user_0=a/postgres,grant_user_1=a/postgres}")
|
||||
57637 | (grant_on_table.ref_table,id,"{grant_user_0=a/postgres,grant_user_1=a/postgres}")
|
||||
57638 | (grant_on_table.ref_table,id,"{grant_user_0=a/postgres,grant_user_1=a/postgres}")
|
||||
57636 | (grant_on_table.ref_table,test_a,"{grant_user_0=a/postgres,grant_user_1=a/postgres}")
|
||||
57637 | (grant_on_table.ref_table,test_a,"{grant_user_0=a/postgres,grant_user_1=a/postgres}")
|
||||
57638 | (grant_on_table.ref_table,test_a,"{grant_user_0=a/postgres,grant_user_1=a/postgres}")
|
||||
57636 | (grant_on_table.ref_table,test_mix,"{grant_user_0=w/postgres,grant_user_1=w/postgres}")
|
||||
57637 | (grant_on_table.ref_table,test_mix,"{grant_user_0=w/postgres,grant_user_1=w/postgres}")
|
||||
57638 | (grant_on_table.ref_table,test_mix,"{grant_user_0=w/postgres,grant_user_1=w/postgres}")
|
||||
57636 | (grant_on_table.ref_table,test_w,"{grant_user_0=w/postgres,grant_user_1=w/postgres}")
|
||||
57637 | (grant_on_table.ref_table,test_w,"{grant_user_0=w/postgres,grant_user_1=w/postgres}")
|
||||
57638 | (grant_on_table.ref_table,test_w,"{grant_user_0=w/postgres,grant_user_1=w/postgres}")
|
||||
(24 rows)
|
||||
|
||||
-- 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 ;
|
||||
nodeport | unnest
|
||||
---------------------------------------------------------------------
|
||||
57636 | (dist_table,)
|
||||
57637 | (dist_table,)
|
||||
57638 | (dist_table,)
|
||||
57636 | (local_table,)
|
||||
57637 | (local_table,)
|
||||
57638 | (local_table,)
|
||||
57636 | (ref_table,{postgres=arwdDxt/postgres})
|
||||
57637 | (ref_table,{postgres=arwdDxt/postgres})
|
||||
57638 | (ref_table,{postgres=arwdDxt/postgres})
|
||||
(9 rows)
|
||||
|
||||
:verify_grant_attributes ;
|
||||
nodeport | unnest
|
||||
---------------------------------------------------------------------
|
||||
(0 rows)
|
||||
|
||||
--
|
||||
-- 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;
|
||||
ERROR: permission denied for table 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;
|
||||
test_r | test_mix
|
||||
---------------------------------------------------------------------
|
||||
| 2
|
||||
(1 row)
|
||||
|
||||
-- granted:
|
||||
DELETE FROM ref_table;
|
||||
-- not granted:
|
||||
SELECT test_a FROM ref_table;
|
||||
ERROR: permission denied for table ref_table
|
||||
-- not granted:
|
||||
UPDATE ref_table SET null_privs = 3;
|
||||
ERROR: permission denied for table ref_table
|
||||
RESET ROLE;
|
||||
-- check on coordinator and workers
|
||||
:verify_grant_table ;
|
||||
nodeport | unnest
|
||||
---------------------------------------------------------------------
|
||||
57636 | (dist_table,)
|
||||
57637 | (dist_table,)
|
||||
57638 | (dist_table,)
|
||||
57636 | (local_table,)
|
||||
57637 | (local_table,)
|
||||
57638 | (local_table,)
|
||||
57636 | (ref_table,"{postgres=arwdDxt/postgres,grant_user_0=d/postgres,grant_user_1=d/postgres}")
|
||||
57637 | (ref_table,"{postgres=arwdDxt/postgres,grant_user_0=d/postgres,grant_user_1=d/postgres}")
|
||||
57638 | (ref_table,"{postgres=arwdDxt/postgres,grant_user_0=d/postgres,grant_user_1=d/postgres}")
|
||||
(9 rows)
|
||||
|
||||
:verify_grant_attributes ;
|
||||
nodeport | unnest
|
||||
---------------------------------------------------------------------
|
||||
57636 | (grant_on_table.ref_table,test_mix,"{grant_user_0=r/postgres,grant_user_1=r/postgres}")
|
||||
57637 | (grant_on_table.ref_table,test_mix,"{grant_user_0=r/postgres,grant_user_1=r/postgres}")
|
||||
57638 | (grant_on_table.ref_table,test_mix,"{grant_user_0=r/postgres,grant_user_1=r/postgres}")
|
||||
57636 | (grant_on_table.ref_table,test_r,"{grant_user_0=r/postgres,grant_user_1=r/postgres}")
|
||||
57637 | (grant_on_table.ref_table,test_r,"{grant_user_0=r/postgres,grant_user_1=r/postgres}")
|
||||
57638 | (grant_on_table.ref_table,test_r,"{grant_user_0=r/postgres,grant_user_1=r/postgres}")
|
||||
(6 rows)
|
||||
|
||||
-- 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 ;
|
||||
nodeport | unnest
|
||||
---------------------------------------------------------------------
|
||||
57636 | (dist_table,)
|
||||
57637 | (dist_table,)
|
||||
57638 | (dist_table,)
|
||||
57636 | (local_table,)
|
||||
57637 | (local_table,)
|
||||
57638 | (local_table,)
|
||||
57636 | (ref_table,{postgres=arwdDxt/postgres})
|
||||
57637 | (ref_table,{postgres=arwdDxt/postgres})
|
||||
57638 | (ref_table,{postgres=arwdDxt/postgres})
|
||||
(9 rows)
|
||||
|
||||
:verify_grant_attributes ;
|
||||
nodeport | unnest
|
||||
---------------------------------------------------------------------
|
||||
(0 rows)
|
||||
|
||||
--
|
||||
-- check we also propagate system columns
|
||||
-- we use only SELECT
|
||||
--
|
||||
SET ROLE grant_user_0;
|
||||
-- not granted yet:
|
||||
SELECT ctid, xmin FROM ref_table;
|
||||
ERROR: permission denied for table 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;
|
||||
ctid | xmin
|
||||
---------------------------------------------------------------------
|
||||
(0 rows)
|
||||
|
||||
-- not granted:
|
||||
SELECT ctid, test_a FROM ref_table;
|
||||
ERROR: permission denied for table ref_table
|
||||
RESET ROLE;
|
||||
-- check on coordinator and workers
|
||||
:verify_grant_table ;
|
||||
nodeport | unnest
|
||||
---------------------------------------------------------------------
|
||||
57636 | (dist_table,)
|
||||
57637 | (dist_table,)
|
||||
57638 | (dist_table,)
|
||||
57636 | (local_table,)
|
||||
57637 | (local_table,)
|
||||
57638 | (local_table,)
|
||||
57636 | (ref_table,{postgres=arwdDxt/postgres})
|
||||
57637 | (ref_table,{postgres=arwdDxt/postgres})
|
||||
57638 | (ref_table,{postgres=arwdDxt/postgres})
|
||||
(9 rows)
|
||||
|
||||
:verify_grant_attributes ;
|
||||
nodeport | unnest
|
||||
---------------------------------------------------------------------
|
||||
57636 | (grant_on_table.ref_table,ctid,{grant_user_0=r/postgres})
|
||||
57637 | (grant_on_table.ref_table,ctid,{grant_user_0=r/postgres})
|
||||
57638 | (grant_on_table.ref_table,ctid,{grant_user_0=r/postgres})
|
||||
57636 | (grant_on_table.ref_table,xmin,{grant_user_0=r/postgres})
|
||||
57637 | (grant_on_table.ref_table,xmin,{grant_user_0=r/postgres})
|
||||
57638 | (grant_on_table.ref_table,xmin,{grant_user_0=r/postgres})
|
||||
(6 rows)
|
||||
|
||||
-- cleanup
|
||||
REVOKE SELECT (ctid, xmin) ON ref_table FROM grant_user_0;
|
||||
-- check on coordinator and workers
|
||||
:verify_grant_table ;
|
||||
nodeport | unnest
|
||||
---------------------------------------------------------------------
|
||||
57636 | (dist_table,)
|
||||
57637 | (dist_table,)
|
||||
57638 | (dist_table,)
|
||||
57636 | (local_table,)
|
||||
57637 | (local_table,)
|
||||
57638 | (local_table,)
|
||||
57636 | (ref_table,{postgres=arwdDxt/postgres})
|
||||
57637 | (ref_table,{postgres=arwdDxt/postgres})
|
||||
57638 | (ref_table,{postgres=arwdDxt/postgres})
|
||||
(9 rows)
|
||||
|
||||
:verify_grant_attributes ;
|
||||
nodeport | unnest
|
||||
---------------------------------------------------------------------
|
||||
(0 rows)
|
||||
|
||||
--
|
||||
-- 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);
|
||||
ERROR: permission denied for table ref_table
|
||||
SET ROLE grant_user_1;
|
||||
-- not granted yet:
|
||||
INSERT INTO ref_table (id, test_mix) VALUES (9, 3);
|
||||
ERROR: permission denied for table ref_table
|
||||
RESET ROLE;
|
||||
GRANT ALL (id) ON ref_table TO grant_user_0;
|
||||
GRANT ALL (id, test_mix) ON ref_table TO grant_user_1;
|
||||
-- ALL cannot be mixed with other privs
|
||||
-- should error:
|
||||
GRANT SELECT (null_privs), ALL (null_privs) ON ref_table TO nogrant_user;
|
||||
ERROR: syntax error at or near "ALL"
|
||||
-- should error:
|
||||
GRANT ALL (null_privs), SELECT (null_privs) ON ref_table TO nogrant_user;
|
||||
ERROR: syntax error at or near ","
|
||||
SET ROLE grant_user_0;
|
||||
-- granted:
|
||||
INSERT INTO ref_table (id) VALUES (13);
|
||||
SET ROLE grant_user_1;
|
||||
-- granted:
|
||||
INSERT INTO ref_table (id, test_mix) VALUES (9, 3);
|
||||
-- not granted:
|
||||
INSERT INTO ref_table (null_privs) VALUES (3);
|
||||
ERROR: permission denied for table ref_table
|
||||
-- granted:
|
||||
SELECT id, test_mix FROM ref_table;
|
||||
id | test_mix
|
||||
---------------------------------------------------------------------
|
||||
13 |
|
||||
9 | 3
|
||||
(2 rows)
|
||||
|
||||
-- not granted:
|
||||
SELECT null_privs FROM ref_table;
|
||||
ERROR: permission denied for table ref_table
|
||||
-- not granted:
|
||||
DELETE FROM ref_table;
|
||||
ERROR: permission denied for table ref_table
|
||||
RESET ROLE;
|
||||
-- check on coordinator and workers
|
||||
:verify_grant_table ;
|
||||
nodeport | unnest
|
||||
---------------------------------------------------------------------
|
||||
57636 | (dist_table,)
|
||||
57637 | (dist_table,)
|
||||
57638 | (dist_table,)
|
||||
57636 | (local_table,)
|
||||
57637 | (local_table,)
|
||||
57638 | (local_table,)
|
||||
57636 | (ref_table,{postgres=arwdDxt/postgres})
|
||||
57637 | (ref_table,{postgres=arwdDxt/postgres})
|
||||
57638 | (ref_table,{postgres=arwdDxt/postgres})
|
||||
(9 rows)
|
||||
|
||||
:verify_grant_attributes ;
|
||||
nodeport | unnest
|
||||
---------------------------------------------------------------------
|
||||
57636 | (grant_on_table.ref_table,id,"{grant_user_0=arwx/postgres,grant_user_1=arwx/postgres}")
|
||||
57637 | (grant_on_table.ref_table,id,"{grant_user_0=arwx/postgres,grant_user_1=arwx/postgres}")
|
||||
57638 | (grant_on_table.ref_table,id,"{grant_user_0=arwx/postgres,grant_user_1=arwx/postgres}")
|
||||
57636 | (grant_on_table.ref_table,test_mix,{grant_user_1=arwx/postgres})
|
||||
57637 | (grant_on_table.ref_table,test_mix,{grant_user_1=arwx/postgres})
|
||||
57638 | (grant_on_table.ref_table,test_mix,{grant_user_1=arwx/postgres})
|
||||
(6 rows)
|
||||
|
||||
-- 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 ;
|
||||
nodeport | unnest
|
||||
---------------------------------------------------------------------
|
||||
57636 | (dist_table,)
|
||||
57637 | (dist_table,)
|
||||
57638 | (dist_table,)
|
||||
57636 | (local_table,)
|
||||
57637 | (local_table,)
|
||||
57638 | (local_table,)
|
||||
57636 | (ref_table,{postgres=arwdDxt/postgres})
|
||||
57637 | (ref_table,{postgres=arwdDxt/postgres})
|
||||
57638 | (ref_table,{postgres=arwdDxt/postgres})
|
||||
(9 rows)
|
||||
|
||||
:verify_grant_attributes ;
|
||||
nodeport | unnest
|
||||
---------------------------------------------------------------------
|
||||
(0 rows)
|
||||
|
||||
--
|
||||
-- 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;
|
||||
ERROR: permission denied for table ref_table
|
||||
RESET ROLE;
|
||||
-- NOTE:
|
||||
-- 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_0;
|
||||
-- check non propagation for local table (we'll just check ACL later, no INSERT testing)
|
||||
GRANT INSERT (test_mix) ON local_table TO grant_user_0;
|
||||
-- check we can propagate also when mixed with distributed table:
|
||||
GRANT SELECT (test_r, test_mix) ON local_table, dist_table TO grant_user_1;
|
||||
SET ROLE grant_user_0;
|
||||
-- granted:
|
||||
SELECT id FROM ref_table
|
||||
UNION ALL SELECT id FROM dist_table
|
||||
UNION ALL SELECT id FROM local_table;
|
||||
id
|
||||
---------------------------------------------------------------------
|
||||
1
|
||||
(1 row)
|
||||
|
||||
SET ROLE grant_user_1;
|
||||
-- granted:
|
||||
SELECT test_r, test_mix FROM dist_table
|
||||
UNION ALL SELECT test_r, test_mix FROM local_table;
|
||||
test_r | test_mix
|
||||
---------------------------------------------------------------------
|
||||
| 3
|
||||
(1 row)
|
||||
|
||||
RESET ROLE;
|
||||
-- check on coordinator and workers
|
||||
-- we pay special attention to local_table privileges here:
|
||||
:verify_grant_table ;
|
||||
nodeport | unnest
|
||||
---------------------------------------------------------------------
|
||||
57636 | (dist_table,)
|
||||
57637 | (dist_table,)
|
||||
57638 | (dist_table,)
|
||||
57636 | (local_table,)
|
||||
57637 | (local_table,)
|
||||
57638 | (local_table,)
|
||||
57636 | (ref_table,{postgres=arwdDxt/postgres})
|
||||
57637 | (ref_table,{postgres=arwdDxt/postgres})
|
||||
57638 | (ref_table,{postgres=arwdDxt/postgres})
|
||||
(9 rows)
|
||||
|
||||
:verify_grant_attributes ;
|
||||
nodeport | unnest
|
||||
---------------------------------------------------------------------
|
||||
57636 | (grant_on_table.dist_table,id,{grant_user_0=r/postgres})
|
||||
57637 | (grant_on_table.dist_table,id,{grant_user_0=r/postgres})
|
||||
57638 | (grant_on_table.dist_table,id,{grant_user_0=r/postgres})
|
||||
57636 | (grant_on_table.dist_table,test_mix,{grant_user_1=r/postgres})
|
||||
57637 | (grant_on_table.dist_table,test_mix,{grant_user_1=r/postgres})
|
||||
57638 | (grant_on_table.dist_table,test_mix,{grant_user_1=r/postgres})
|
||||
57636 | (grant_on_table.dist_table,test_r,{grant_user_1=r/postgres})
|
||||
57637 | (grant_on_table.dist_table,test_r,{grant_user_1=r/postgres})
|
||||
57638 | (grant_on_table.dist_table,test_r,{grant_user_1=r/postgres})
|
||||
57636 | (grant_on_table.local_table,id,{grant_user_0=r/postgres})
|
||||
57636 | (grant_on_table.local_table,test_mix,"{grant_user_0=a/postgres,grant_user_1=r/postgres}")
|
||||
57636 | (grant_on_table.local_table,test_r,{grant_user_1=r/postgres})
|
||||
57636 | (grant_on_table.ref_table,id,{grant_user_0=r/postgres})
|
||||
57637 | (grant_on_table.ref_table,id,{grant_user_0=r/postgres})
|
||||
57638 | (grant_on_table.ref_table,id,{grant_user_0=r/postgres})
|
||||
(15 rows)
|
||||
|
||||
-- cleanup
|
||||
REVOKE SELECT (id) ON ALL TABLES IN SCHEMA grant_on_table FROM grant_user_0;
|
||||
-- check non propagation for local table (we'll just check ACL later, no INSERT testing)
|
||||
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 ;
|
||||
nodeport | unnest
|
||||
---------------------------------------------------------------------
|
||||
57636 | (dist_table,)
|
||||
57637 | (dist_table,)
|
||||
57638 | (dist_table,)
|
||||
57636 | (local_table,)
|
||||
57637 | (local_table,)
|
||||
57638 | (local_table,)
|
||||
57636 | (ref_table,{postgres=arwdDxt/postgres})
|
||||
57637 | (ref_table,{postgres=arwdDxt/postgres})
|
||||
57638 | (ref_table,{postgres=arwdDxt/postgres})
|
||||
(9 rows)
|
||||
|
||||
:verify_grant_attributes ;
|
||||
nodeport | unnest
|
||||
---------------------------------------------------------------------
|
||||
(0 rows)
|
||||
|
||||
--
|
||||
-- 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;
|
||||
-- not granted yet:
|
||||
SELECT test_r FROM ref_table;
|
||||
ERROR: permission denied for table ref_table
|
||||
RESET ROLE;
|
||||
GRANT TRUNCATE (null_privs), SELECT (null_privs) ON ref_table TO nogrant_user;
|
||||
ERROR: invalid privilege type TRUNCATE for column
|
||||
SET ROLE grant_user_0;
|
||||
-- still not granted:
|
||||
SELECT test_r FROM ref_table;
|
||||
ERROR: permission denied for table ref_table
|
||||
-- still not granted:
|
||||
TRUNCATE ref_table;
|
||||
ERROR: permission denied for table ref_table
|
||||
RESET ROLE;
|
||||
-- check on coordinator and workers
|
||||
:verify_grant_table ;
|
||||
nodeport | unnest
|
||||
---------------------------------------------------------------------
|
||||
57636 | (dist_table,)
|
||||
57637 | (dist_table,)
|
||||
57638 | (dist_table,)
|
||||
57636 | (local_table,)
|
||||
57637 | (local_table,)
|
||||
57638 | (local_table,)
|
||||
57636 | (ref_table,{postgres=arwdDxt/postgres})
|
||||
57637 | (ref_table,{postgres=arwdDxt/postgres})
|
||||
57638 | (ref_table,{postgres=arwdDxt/postgres})
|
||||
(9 rows)
|
||||
|
||||
:verify_grant_attributes ;
|
||||
nodeport | unnest
|
||||
---------------------------------------------------------------------
|
||||
(0 rows)
|
||||
|
||||
-- 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;
|
||||
ERROR: operation is not allowed on this node
|
||||
HINT: Connect to the coordinator and run it again.
|
||||
\c - - - :master_port
|
||||
SET search_path TO grant_on_table;
|
||||
-- check on coordinator and workers
|
||||
:verify_grant_table ;
|
||||
nodeport | unnest
|
||||
---------------------------------------------------------------------
|
||||
57636 | (dist_table,)
|
||||
57637 | (dist_table,)
|
||||
57638 | (dist_table,)
|
||||
57636 | (local_table,)
|
||||
57637 | (local_table,)
|
||||
57638 | (local_table,)
|
||||
57636 | (ref_table,{postgres=arwdDxt/postgres})
|
||||
57637 | (ref_table,{postgres=arwdDxt/postgres})
|
||||
57638 | (ref_table,{postgres=arwdDxt/postgres})
|
||||
(9 rows)
|
||||
|
||||
:verify_grant_attributes ;
|
||||
nodeport | unnest
|
||||
---------------------------------------------------------------------
|
||||
(0 rows)
|
||||
|
||||
-- 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;
|
||||
ERROR: permission denied for table ref_table
|
||||
SET ROLE grant_user_1;
|
||||
-- not granted yet:
|
||||
SELECT test_r, test_mix FROM ref_table;
|
||||
ERROR: permission denied for table 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;
|
||||
test_r | test_mix
|
||||
---------------------------------------------------------------------
|
||||
(0 rows)
|
||||
|
||||
RESET ROLE;
|
||||
-- check on coordinator and workers
|
||||
:verify_grant_table ;
|
||||
nodeport | unnest
|
||||
---------------------------------------------------------------------
|
||||
57636 | (dist_table,)
|
||||
57637 | (dist_table,)
|
||||
57638 | (dist_table,)
|
||||
57636 | (local_table,)
|
||||
57637 | (local_table,)
|
||||
57638 | (local_table,)
|
||||
57636 | (ref_table,{postgres=arwdDxt/postgres})
|
||||
57637 | (ref_table,{postgres=arwdDxt/postgres})
|
||||
57638 | (ref_table,{postgres=arwdDxt/postgres})
|
||||
(9 rows)
|
||||
|
||||
:verify_grant_attributes ;
|
||||
nodeport | unnest
|
||||
---------------------------------------------------------------------
|
||||
57636 | (grant_on_table.ref_table,test_mix,"{grant_user_0=r*/postgres,grant_user_1=r/grant_user_0}")
|
||||
57637 | (grant_on_table.ref_table,test_mix,"{grant_user_0=r*/postgres,grant_user_1=r/grant_user_0}")
|
||||
57638 | (grant_on_table.ref_table,test_mix,"{grant_user_0=r*/postgres,grant_user_1=r/grant_user_0}")
|
||||
57636 | (grant_on_table.ref_table,test_r,"{grant_user_0=r*/postgres,grant_user_1=r/grant_user_0}")
|
||||
57637 | (grant_on_table.ref_table,test_r,"{grant_user_0=r*/postgres,grant_user_1=r/grant_user_0}")
|
||||
57638 | (grant_on_table.ref_table,test_r,"{grant_user_0=r*/postgres,grant_user_1=r/grant_user_0}")
|
||||
(6 rows)
|
||||
|
||||
-- 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 ;
|
||||
nodeport | unnest
|
||||
---------------------------------------------------------------------
|
||||
57636 | (dist_table,)
|
||||
57637 | (dist_table,)
|
||||
57638 | (dist_table,)
|
||||
57636 | (local_table,)
|
||||
57637 | (local_table,)
|
||||
57638 | (local_table,)
|
||||
57636 | (ref_table,{postgres=arwdDxt/postgres})
|
||||
57637 | (ref_table,{postgres=arwdDxt/postgres})
|
||||
57638 | (ref_table,{postgres=arwdDxt/postgres})
|
||||
(9 rows)
|
||||
|
||||
:verify_grant_attributes ;
|
||||
nodeport | unnest
|
||||
---------------------------------------------------------------------
|
||||
57636 | (grant_on_table.ref_table,test_mix,{grant_user_0=r*/postgres})
|
||||
57637 | (grant_on_table.ref_table,test_mix,{grant_user_0=r*/postgres})
|
||||
57638 | (grant_on_table.ref_table,test_mix,{grant_user_0=r*/postgres})
|
||||
57636 | (grant_on_table.ref_table,test_r,{grant_user_0=r*/postgres})
|
||||
57637 | (grant_on_table.ref_table,test_r,{grant_user_0=r*/postgres})
|
||||
57638 | (grant_on_table.ref_table,test_r,{grant_user_0=r*/postgres})
|
||||
(6 rows)
|
||||
|
||||
-- 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 ;
|
||||
nodeport | unnest
|
||||
---------------------------------------------------------------------
|
||||
57636 | (dist_table,)
|
||||
57637 | (dist_table,)
|
||||
57638 | (dist_table,)
|
||||
57636 | (local_table,)
|
||||
57637 | (local_table,)
|
||||
57638 | (local_table,)
|
||||
57636 | (ref_table,{postgres=arwdDxt/postgres})
|
||||
57637 | (ref_table,{postgres=arwdDxt/postgres})
|
||||
57638 | (ref_table,{postgres=arwdDxt/postgres})
|
||||
(9 rows)
|
||||
|
||||
:verify_grant_attributes ;
|
||||
nodeport | unnest
|
||||
---------------------------------------------------------------------
|
||||
57636 | (grant_on_table.ref_table,test_mix,{grant_user_0=r/postgres})
|
||||
57637 | (grant_on_table.ref_table,test_mix,{grant_user_0=r/postgres})
|
||||
57638 | (grant_on_table.ref_table,test_mix,{grant_user_0=r/postgres})
|
||||
57636 | (grant_on_table.ref_table,test_r,{grant_user_0=r/postgres})
|
||||
57637 | (grant_on_table.ref_table,test_r,{grant_user_0=r/postgres})
|
||||
57638 | (grant_on_table.ref_table,test_r,{grant_user_0=r/postgres})
|
||||
(6 rows)
|
||||
|
||||
-- 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 ;
|
||||
nodeport | unnest
|
||||
---------------------------------------------------------------------
|
||||
57636 | (dist_table,)
|
||||
57637 | (dist_table,)
|
||||
57638 | (dist_table,)
|
||||
57636 | (local_table,)
|
||||
57637 | (local_table,)
|
||||
57638 | (local_table,)
|
||||
57636 | (ref_table,{postgres=arwdDxt/postgres})
|
||||
57637 | (ref_table,{postgres=arwdDxt/postgres})
|
||||
57638 | (ref_table,{postgres=arwdDxt/postgres})
|
||||
(9 rows)
|
||||
|
||||
:verify_grant_attributes ;
|
||||
nodeport | unnest
|
||||
---------------------------------------------------------------------
|
||||
(0 rows)
|
||||
|
||||
-- prevent useless messages on DROP objects.
|
||||
SET client_min_messages TO ERROR;
|
||||
DROP TABLE dist_table, ref_table;
|
||||
SELECT result FROM run_command_on_all_nodes('DROP TABLE grant_on_table.local_table');
|
||||
result
|
||||
---------------------------------------------------------------------
|
||||
DROP TABLE
|
||||
DROP TABLE
|
||||
DROP TABLE
|
||||
(3 rows)
|
||||
|
||||
RESET client_min_messages;
|
||||
--
|
||||
-- check we propagate privileges when GRANTed before distributed and when adding a node
|
||||
-- we use only SELECT
|
||||
--
|
||||
-- test propagation on columns when distributing the table after GRANT has been executed
|
||||
CREATE TABLE grant_table_propagated (id int primary key);
|
||||
GRANT SELECT (id) ON grant_table_propagated TO grant_user_0;
|
||||
SELECT create_distributed_table('grant_table_propagated', 'id');
|
||||
create_distributed_table
|
||||
---------------------------------------------------------------------
|
||||
|
||||
(1 row)
|
||||
|
||||
SET ROLE grant_user_0;
|
||||
-- granted:
|
||||
SELECT id FROM grant_table_propagated;
|
||||
id
|
||||
---------------------------------------------------------------------
|
||||
(0 rows)
|
||||
|
||||
RESET ROLE;
|
||||
-- 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'') $$) 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''::regclass) AND attacl IS NOT NULL $$) join pg_dist_node using (nodeid) ORDER BY 2, 1'
|
||||
:verify_grant_table ;
|
||||
nodeport | unnest
|
||||
---------------------------------------------------------------------
|
||||
57636 | (grant_table_propagated,)
|
||||
57637 | (grant_table_propagated,)
|
||||
57638 | (grant_table_propagated,)
|
||||
(3 rows)
|
||||
|
||||
:verify_grant_attributes ;
|
||||
nodeport | unnest
|
||||
---------------------------------------------------------------------
|
||||
57636 | (grant_on_table.grant_table_propagated,id,{grant_user_0=r/postgres})
|
||||
57637 | (grant_on_table.grant_table_propagated,id,{grant_user_0=r/postgres})
|
||||
57638 | (grant_on_table.grant_table_propagated,id,{grant_user_0=r/postgres})
|
||||
(3 rows)
|
||||
|
||||
-- cleanup
|
||||
REVOKE SELECT (id) ON grant_table_propagated FROM grant_user_0;
|
||||
:verify_grant_table ;
|
||||
nodeport | unnest
|
||||
---------------------------------------------------------------------
|
||||
57636 | (grant_table_propagated,)
|
||||
57637 | (grant_table_propagated,)
|
||||
57638 | (grant_table_propagated,)
|
||||
(3 rows)
|
||||
|
||||
:verify_grant_attributes ;
|
||||
nodeport | unnest
|
||||
---------------------------------------------------------------------
|
||||
(0 rows)
|
||||
|
||||
-- prevent useless messages on DROP objects.
|
||||
SET client_min_messages TO ERROR;
|
||||
DROP TABLE grant_table_propagated;
|
||||
RESET client_min_messages;
|
||||
-- similar test but adding a node after the fact
|
||||
-- remove one of the worker nodes:
|
||||
SELECT citus_remove_node('localhost', :worker_2_port);
|
||||
citus_remove_node
|
||||
---------------------------------------------------------------------
|
||||
|
||||
(1 row)
|
||||
|
||||
CREATE TABLE grant_table_propagated_after (id int primary key);
|
||||
SET citus.shard_replication_factor TO 1;
|
||||
SELECT create_distributed_table('grant_table_propagated_after', 'id');
|
||||
create_distributed_table
|
||||
---------------------------------------------------------------------
|
||||
|
||||
(1 row)
|
||||
|
||||
SET citus.shard_replication_factor TO 2;
|
||||
GRANT SELECT (id) ON grant_table_propagated_after TO grant_user_0;
|
||||
-- add back the worker node
|
||||
SELECT FROM citus_add_node('localhost', :worker_2_port);
|
||||
--
|
||||
(1 row)
|
||||
|
||||
-- granted:
|
||||
SELECT id FROM grant_table_propagated_after;
|
||||
id
|
||||
---------------------------------------------------------------------
|
||||
(0 rows)
|
||||
|
||||
-- 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 ;
|
||||
nodeport | unnest
|
||||
---------------------------------------------------------------------
|
||||
57636 | (grant_table_propagated_after,)
|
||||
57637 | (grant_table_propagated_after,)
|
||||
57638 | (grant_table_propagated_after,)
|
||||
(3 rows)
|
||||
|
||||
:verify_grant_attributes ;
|
||||
nodeport | unnest
|
||||
---------------------------------------------------------------------
|
||||
57636 | (grant_on_table.grant_table_propagated_after,id,{grant_user_0=r/postgres})
|
||||
57637 | (grant_on_table.grant_table_propagated_after,id,{grant_user_0=r/postgres})
|
||||
57638 | (grant_on_table.grant_table_propagated_after,id,{grant_user_0=r/postgres})
|
||||
(3 rows)
|
||||
|
||||
-- cleanup
|
||||
REVOKE SELECT (id) ON grant_table_propagated_after FROM grant_user_0;
|
||||
:verify_grant_table ;
|
||||
nodeport | unnest
|
||||
---------------------------------------------------------------------
|
||||
57636 | (grant_table_propagated_after,)
|
||||
57637 | (grant_table_propagated_after,)
|
||||
57638 | (grant_table_propagated_after,)
|
||||
(3 rows)
|
||||
|
||||
:verify_grant_attributes ;
|
||||
nodeport | unnest
|
||||
---------------------------------------------------------------------
|
||||
(0 rows)
|
||||
|
||||
-- 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.
|
||||
SET client_min_messages TO ERROR;
|
||||
DROP SCHEMA grant_on_table CASCADE;
|
||||
DROP ROLE grant_user_0, grant_user_1;
|
||||
RESET client_min_messages;
|
||||
RESET search_path;
|
|
@ -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;
|
||||
|
|
|
@ -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;
|
||||
|
|
|
@ -57,6 +57,7 @@ test: multi_metadata_attributes
|
|||
|
||||
test: multi_read_from_secondaries
|
||||
|
||||
test: grant_on_table_propagation
|
||||
test: grant_on_database_propagation
|
||||
test: alter_database_propagation
|
||||
|
||||
|
|
|
@ -0,0 +1,444 @@
|
|||
-- PostgreSQL 17 introduces MAINTAIN privilege, this change the default output
|
||||
-- of some test queries.
|
||||
--
|
||||
-- Alternative "grant_on_table_propagation_0.out" and this comment can be
|
||||
-- removed when support for PostgreSQL versions < 17 is dropped.
|
||||
|
||||
SHOW server_version \gset
|
||||
SELECT substring(:'server_version', '\d+')::int >= 17 AS server_version_ge_17;
|
||||
|
||||
--
|
||||
-- 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 on all nodes and 2 managed by citus
|
||||
-- null_privs ACL must not be updated in anyway.
|
||||
CREATE TABLE dist_table (id bigint GENERATED BY DEFAULT AS IDENTITY primary key
|
||||
, test_a int -- test for INSERT
|
||||
, test_r text -- test for SELECT
|
||||
, 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 ref_table (id bigint GENERATED BY DEFAULT AS IDENTITY primary key
|
||||
, test_a int -- test for INSERT
|
||||
, test_r text -- test for SELECT
|
||||
, test_w text -- test for UPDATE
|
||||
, test_mix int -- test for ALL
|
||||
, null_privs text
|
||||
);
|
||||
SELECT create_reference_table('ref_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 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
|
||||
--
|
||||
|
||||
--
|
||||
-- when executing a table level grant, "postgres" is add/listed in pg_class.relacl
|
||||
-- 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;
|
||||
-- not granted yet:
|
||||
SELECT test_r FROM ref_table;
|
||||
RESET ROLE;
|
||||
GRANT SELECT (test_r) ON ref_table TO grant_user_0;
|
||||
SET ROLE grant_user_0;
|
||||
-- granted:
|
||||
SELECT test_r FROM ref_table;
|
||||
-- not granted:
|
||||
SELECT test_a FROM ref_table;
|
||||
SET ROLE grant_user_1;
|
||||
-- not granted:
|
||||
SELECT test_r FROM ref_table;
|
||||
RESET ROLE;
|
||||
|
||||
-- check on coordinator and workers
|
||||
:verify_grant_table ;
|
||||
:verify_grant_attributes ;
|
||||
|
||||
-- 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;
|
||||
-- not granted yet:
|
||||
INSERT INTO ref_table (test_a) VALUES (1);
|
||||
RESET ROLE;
|
||||
-- we would prefer not have to grant INSERT (id) as expected in the standard but
|
||||
-- Citus rewrite queries with such attributes, which prevent standard to be applied.
|
||||
GRANT INSERT (id, test_a), UPDATE (test_w, test_mix) ON ref_table, dist_table TO grant_user_0, grant_user_1;
|
||||
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;
|
||||
|
||||
-- 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, test_mix) ON ref_table TO grant_user_1;
|
||||
-- ALL cannot be mixed with other privs
|
||||
-- should error:
|
||||
GRANT SELECT (null_privs), ALL (null_privs) ON ref_table TO nogrant_user;
|
||||
-- should error:
|
||||
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;
|
||||
-- granted:
|
||||
INSERT INTO ref_table (id, test_mix) VALUES (9, 3);
|
||||
-- not granted:
|
||||
INSERT INTO ref_table (null_privs) VALUES (3);
|
||||
-- granted:
|
||||
SELECT id, test_mix FROM ref_table;
|
||||
-- not granted:
|
||||
SELECT null_privs FROM ref_table;
|
||||
-- not granted:
|
||||
DELETE FROM ref_table;
|
||||
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
|
||||
-- but is accepted by PostgreSQL - non documented feature
|
||||
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)
|
||||
GRANT INSERT (test_mix) ON local_table TO grant_user_0;
|
||||
-- check we can propagate also when mixed with distributed table:
|
||||
GRANT SELECT (test_r, test_mix) ON local_table, dist_table TO grant_user_1;
|
||||
SET ROLE grant_user_0;
|
||||
-- granted:
|
||||
SELECT id FROM ref_table
|
||||
UNION ALL SELECT id FROM dist_table
|
||||
UNION ALL SELECT id FROM local_table;
|
||||
SET ROLE grant_user_1;
|
||||
-- granted:
|
||||
SELECT test_r, test_mix FROM dist_table
|
||||
UNION ALL SELECT test_r, test_mix FROM local_table;
|
||||
RESET ROLE;
|
||||
|
||||
-- check on coordinator and workers
|
||||
-- we pay special attention to local_table privileges here:
|
||||
:verify_grant_table ;
|
||||
:verify_grant_attributes ;
|
||||
|
||||
-- cleanup
|
||||
REVOKE SELECT (id) ON ALL TABLES IN SCHEMA grant_on_table FROM grant_user_0;
|
||||
-- check non propagation for local table (we'll just check ACL later, no INSERT testing)
|
||||
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;
|
||||
-- not granted yet:
|
||||
SELECT test_r FROM ref_table;
|
||||
RESET ROLE;
|
||||
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;
|
||||
|
||||
-- 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.
|
||||
SET client_min_messages TO ERROR;
|
||||
DROP TABLE dist_table, ref_table;
|
||||
SELECT result FROM run_command_on_all_nodes('DROP TABLE grant_on_table.local_table');
|
||||
RESET client_min_messages;
|
||||
|
||||
--
|
||||
-- check we propagate privileges when GRANTed before distributed and when adding a node
|
||||
-- we use only SELECT
|
||||
--
|
||||
-- test propagation on columns when distributing the table after GRANT has been executed
|
||||
CREATE TABLE grant_table_propagated (id int primary key);
|
||||
GRANT SELECT (id) ON grant_table_propagated TO grant_user_0;
|
||||
SELECT create_distributed_table('grant_table_propagated', 'id');
|
||||
SET ROLE grant_user_0;
|
||||
-- granted:
|
||||
SELECT id FROM grant_table_propagated;
|
||||
RESET ROLE;
|
||||
|
||||
-- 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'') $$) 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''::regclass) AND attacl IS NOT NULL $$) join pg_dist_node using (nodeid) ORDER BY 2, 1'
|
||||
|
||||
:verify_grant_table ;
|
||||
:verify_grant_attributes ;
|
||||
|
||||
-- cleanup
|
||||
REVOKE SELECT (id) ON grant_table_propagated 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;
|
||||
RESET client_min_messages;
|
||||
|
||||
-- similar test but adding a node after the fact
|
||||
-- remove one of the worker nodes:
|
||||
SELECT citus_remove_node('localhost', :worker_2_port);
|
||||
CREATE TABLE grant_table_propagated_after (id int primary key);
|
||||
SET citus.shard_replication_factor TO 1;
|
||||
SELECT create_distributed_table('grant_table_propagated_after', 'id');
|
||||
SET citus.shard_replication_factor TO 2;
|
||||
GRANT SELECT (id) ON grant_table_propagated_after TO grant_user_0;
|
||||
-- add back the worker node
|
||||
SELECT FROM citus_add_node('localhost', :worker_2_port);
|
||||
|
||||
-- granted:
|
||||
SELECT id FROM grant_table_propagated_after;
|
||||
|
||||
-- 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
|
||||
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.
|
||||
SET client_min_messages TO ERROR;
|
||||
DROP SCHEMA grant_on_table CASCADE;
|
||||
DROP ROLE grant_user_0, grant_user_1;
|
||||
RESET client_min_messages;
|
||||
RESET search_path;
|
|
@ -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;
|
||||
|
|
Loading…
Reference in New Issue