Thread: GRANT ON ALL IN schema
Hi all, I am thinking about implementing GRANT ON ALL TABLES IN schema TODO item. I saw many people sending proposals to the list but nobody seemed to actually do anything. I have few questions and problems to iron out before I can start the implementation. I would also like to note that I am not going to implement the second part (GRANT ON NEW TABLES) of the proposed TODO item as there seems to be better solution to this which is Default ACLs (http://wiki.postgresql.org/wiki/DefaultACL) - btw is anybody working on that ? If not I am interested in doing it also as a complementary patch to this one. Anyway back to my thoughts about this patch. First of all I see problem with the proposed syntax. For this syntax I think TABLES (FUNCTIONS, SEQUENCES, etc) would have to be added to keywords which is problematic because there are views named tables, sequences, views in information_schema so we can't really make them keywords. I have no idea how to get around this and I don't see good alternative syntax either. This is main and only real problem I have. The other stuff is minor, like do we want this only for tables, sequences, functions and views or do we want it for every object for which we have GRANT command. Also in standard GRANT there is no distinction between table and view, I guess in this case there should be. -- Regards Petr Jelinek (PJMODOS)
Petr Jelinek wrote: > Anyway back to my thoughts about this patch. First of all I see problem > with the proposed syntax. For this syntax I think TABLES (FUNCTIONS, > SEQUENCES, etc) would have to be added to keywords which is problematic > because there are views named tables, sequences, views in > information_schema so we can't really make them keywords. I have no idea > how to get around this and I don't see good alternative syntax either. > This is main and only real problem I have. Erm, seems like the problem was just me overlooking something in gram.y (I forgot to add those keywords to unreserved_keyword) so no real problems, but I'd still like to hear answers to those other questions in my previous email. -- Regards Petr Jelinek (PJMODOS)
So, here is the first version of the patch. It includes functionality itself, simple regression test and also very simple documentation. The patch allows "GRANT ON ALL TABLES/VIEWS/FUNCTIONS/SEQUENCES IN schemaname, schemaname2 TO username" and same thing for REVOKE. Words TABLES, VIEWS, FUNCTIONS and SEQUENCES were added as unreserved keywords. Unfortunately I was unable to create syntax with optional SCHEMA keyword after IN (shift/reduce conflicts), if it's needed maybe somebody with better bison knowledge might add it. Also since this patch introduces VIEWS as object with grantable privileges, I added GRANT ON VIEW foo syntax which is more or less synonymous to GRANT ON TABLE foo syntax. It felt weird to have GRANT ON ALL VIEWS but not GRANT ON VIEW. Any comments/suggestions are welcome (I especially wonder if the use of list_union_ptr is acceptable). -- Regards Petr Jelinek (PJMODOS) diff --git a/doc/src/sgml/ref/grant.sgml b/doc/src/sgml/ref/grant.sgml index bf963b8..7ddbd25 100644 *** a/doc/src/sgml/ref/grant.sgml --- b/doc/src/sgml/ref/grant.sgml *************** PostgreSQL documentation *** 23,39 **** <synopsis> GRANT { { SELECT | INSERT | UPDATE | DELETE | TRUNCATE | REFERENCES | TRIGGER } [,...] | ALL [ PRIVILEGES ] } ! ON [ TABLE ] <replaceable class="PARAMETER">tablename</replaceable> [, ...] TO { [ GROUP ] <replaceable class="PARAMETER">rolename</replaceable> | PUBLIC } [, ...] [ WITH GRANT OPTION ] GRANT { { SELECT | INSERT | UPDATE | REFERENCES } ( <replaceable class="PARAMETER">column</replaceable> [, ...] ) [,...] | ALL [ PRIVILEGES ] ( <replaceable class="PARAMETER">column</replaceable> [, ...] ) } ! ON [ TABLE ] <replaceable class="PARAMETER">tablename</replaceable> [, ...] TO { [ GROUP ] <replaceable class="PARAMETER">rolename</replaceable> | PUBLIC } [, ...] [ WITH GRANT OPTION ] GRANT { { USAGE | SELECT | UPDATE } [,...] | ALL [ PRIVILEGES ] } ! ON SEQUENCE <replaceable class="PARAMETER">sequencename</replaceable> [, ...] TO { [ GROUP ] <replaceable class="PARAMETER">rolename</replaceable> | PUBLIC } [, ...] [ WITH GRANT OPTION ] GRANT { { CREATE | CONNECT | TEMPORARY | TEMP } [,...] | ALL [ PRIVILEGES ] } --- 23,41 ---- <synopsis> GRANT { { SELECT | INSERT | UPDATE | DELETE | TRUNCATE | REFERENCES | TRIGGER } [,...] | ALL [ PRIVILEGES ] } ! ON { { [ TABLE | VIEW ] <replaceable class="PARAMETER">tablename</replaceable> [, ...] } ! | ALL [ TABLES | VIEWS ] IN <replaceable>schemaname</replaceable> [, ...] } TO { [ GROUP ] <replaceable class="PARAMETER">rolename</replaceable> | PUBLIC } [, ...] [ WITH GRANT OPTION ] GRANT { { SELECT | INSERT | UPDATE | REFERENCES } ( <replaceable class="PARAMETER">column</replaceable> [, ...] ) [,...] | ALL [ PRIVILEGES ] ( <replaceable class="PARAMETER">column</replaceable> [, ...] ) } ! ON [ TABLE | VIEW ] <replaceable class="PARAMETER">tablename</replaceable> [, ...] TO { [ GROUP ] <replaceable class="PARAMETER">rolename</replaceable> | PUBLIC } [, ...] [ WITH GRANT OPTION ] GRANT { { USAGE | SELECT | UPDATE } [,...] | ALL [ PRIVILEGES ] } ! ON { SEQUENCE <replaceable class="PARAMETER">sequencename</replaceable> [, ...] ! | ALL SEQUENCES IN <replaceable>schemaname</replaceable> [, ...] } TO { [ GROUP ] <replaceable class="PARAMETER">rolename</replaceable> | PUBLIC } [, ...] [ WITH GRANT OPTION ] GRANT { { CREATE | CONNECT | TEMPORARY | TEMP } [,...] | ALL [ PRIVILEGES ] } *************** GRANT { USAGE | ALL [ PRIVILEGES ] } *** 49,55 **** TO { [ GROUP ] <replaceable class="PARAMETER">rolename</replaceable> | PUBLIC } [, ...] [ WITH GRANT OPTION ] GRANT { EXECUTE | ALL [ PRIVILEGES ] } ! ON FUNCTION <replaceable>funcname</replaceable> ( [ [ <replaceable class="parameter">argmode</replaceable> ] [ <replaceableclass="parameter">argname</replaceable> ] <replaceable class="parameter">argtype</replaceable> [, ...] ] ) [,...] TO { [ GROUP ] <replaceable class="PARAMETER">rolename</replaceable> | PUBLIC } [, ...] [ WITH GRANT OPTION ] GRANT { USAGE | ALL [ PRIVILEGES ] } --- 51,58 ---- TO { [ GROUP ] <replaceable class="PARAMETER">rolename</replaceable> | PUBLIC } [, ...] [ WITH GRANT OPTION ] GRANT { EXECUTE | ALL [ PRIVILEGES ] } ! ON { FUNCTION <replaceable>funcname</replaceable> ( [ [ <replaceable class="parameter">argmode</replaceable> ] [ <replaceableclass="parameter">argname</replaceable> ] <replaceable class="parameter">argtype</replaceable> [, ...] ] ) [,...] ! | ALL FUNCTIONS IN <replaceable>schemaname</replaceable> [, ...] } TO { [ GROUP ] <replaceable class="PARAMETER">rolename</replaceable> | PUBLIC } [, ...] [ WITH GRANT OPTION ] GRANT { USAGE | ALL [ PRIVILEGES ] } *************** GRANT <replaceable class="PARAMETER">rol *** 143,148 **** --- 146,158 ---- </para> <para> + There is also the posibility of granting permissions to all objects of + given type inside one or multiple schemas. This functionality is supported + for tables, views, sequences and functions and can done by using + ALL TABLES IN schemanema syntax in place of object name. + </para> + + <para> The possible privileges are: <variablelist> diff --git a/doc/src/sgml/ref/revoke.sgml b/doc/src/sgml/ref/revoke.sgml index 8d62580..ac0905f 100644 *** a/doc/src/sgml/ref/revoke.sgml --- b/doc/src/sgml/ref/revoke.sgml *************** PostgreSQL documentation *** 24,44 **** REVOKE [ GRANT OPTION FOR ] { { SELECT | INSERT | UPDATE | DELETE | TRUNCATE | REFERENCES | TRIGGER } [,...] | ALL [ PRIVILEGES ] } ! ON [ TABLE ] <replaceable class="PARAMETER">tablename</replaceable> [, ...] FROM { [ GROUP ] <replaceable class="PARAMETER">rolename</replaceable> | PUBLIC } [, ...] [ CASCADE | RESTRICT ] REVOKE [ GRANT OPTION FOR ] { { SELECT | INSERT | UPDATE | REFERENCES } ( <replaceable class="PARAMETER">column</replaceable> [, ...] ) [,...] | ALL [ PRIVILEGES ] ( <replaceable class="PARAMETER">column</replaceable> [, ...] ) } ! ON [ TABLE ] <replaceable class="PARAMETER">tablename</replaceable> [, ...] FROM { [ GROUP ] <replaceable class="PARAMETER">rolename</replaceable> | PUBLIC } [, ...] [ CASCADE | RESTRICT ] REVOKE [ GRANT OPTION FOR ] { { USAGE | SELECT | UPDATE } [,...] | ALL [ PRIVILEGES ] } ! ON SEQUENCE <replaceable class="PARAMETER">sequencename</replaceable> [, ...] FROM { [ GROUP ] <replaceable class="PARAMETER">rolename</replaceable> | PUBLIC } [, ...] [ CASCADE | RESTRICT ] --- 24,46 ---- REVOKE [ GRANT OPTION FOR ] { { SELECT | INSERT | UPDATE | DELETE | TRUNCATE | REFERENCES | TRIGGER } [,...] | ALL [ PRIVILEGES ] } ! ON { { [ TABLE | VIEW ] <replaceable class="PARAMETER">tablename</replaceable> [, ...] } ! | ALL [ TABLES | VIEWS ] IN <replaceable>schemaname</replaceable> [, ...] } FROM { [ GROUP ] <replaceable class="PARAMETER">rolename</replaceable> | PUBLIC } [, ...] [ CASCADE | RESTRICT ] REVOKE [ GRANT OPTION FOR ] { { SELECT | INSERT | UPDATE | REFERENCES } ( <replaceable class="PARAMETER">column</replaceable> [, ...] ) [,...] | ALL [ PRIVILEGES ] ( <replaceable class="PARAMETER">column</replaceable> [, ...] ) } ! ON [ TABLE | VIEW ] <replaceable class="PARAMETER">tablename</replaceable> [, ...] FROM { [ GROUP ] <replaceable class="PARAMETER">rolename</replaceable> | PUBLIC } [, ...] [ CASCADE | RESTRICT ] REVOKE [ GRANT OPTION FOR ] { { USAGE | SELECT | UPDATE } [,...] | ALL [ PRIVILEGES ] } ! ON { SEQUENCE <replaceable class="PARAMETER">sequencename</replaceable> [, ...] ! | ALL SEQUENCES IN <replaceable>schemaname</replaceable> [, ...] } FROM { [ GROUP ] <replaceable class="PARAMETER">rolename</replaceable> | PUBLIC } [, ...] [ CASCADE | RESTRICT ] *************** REVOKE [ GRANT OPTION FOR ] *** 62,68 **** REVOKE [ GRANT OPTION FOR ] { EXECUTE | ALL [ PRIVILEGES ] } ! ON FUNCTION <replaceable>funcname</replaceable> ( [ [ <replaceable class="parameter">argmode</replaceable> ] [ <replaceableclass="parameter">argname</replaceable> ] <replaceable class="parameter">argtype</replaceable> [, ...] ] ) [,...] FROM { [ GROUP ] <replaceable class="PARAMETER">rolename</replaceable> | PUBLIC } [, ...] [ CASCADE | RESTRICT ] --- 64,71 ---- REVOKE [ GRANT OPTION FOR ] { EXECUTE | ALL [ PRIVILEGES ] } ! ON { FUNCTION <replaceable>funcname</replaceable> ( [ [ <replaceable class="parameter">argmode</replaceable> ] [ <replaceableclass="parameter">argname</replaceable> ] <replaceable class="parameter">argtype</replaceable> [, ...] ] ) [,...] ! | ALL FUNCTIONS IN <replaceable>schemaname</replaceable> [, ...] } FROM { [ GROUP ] <replaceable class="PARAMETER">rolename</replaceable> | PUBLIC } [, ...] [ CASCADE | RESTRICT ] diff --git a/src/backend/catalog/aclchk.c b/src/backend/catalog/aclchk.c index ec4aaf0..98fbd27 100644 *** a/src/backend/catalog/aclchk.c --- b/src/backend/catalog/aclchk.c *************** static void ExecGrant_Namespace(Internal *** 61,66 **** --- 61,68 ---- static void ExecGrant_Tablespace(InternalGrant *grantStmt); static List *objectNamesToOids(GrantObjectType objtype, List *objnames); + static List *getNamespacesObjectsOids(GrantObjectType objtype, List *nspnames); + static List *getRelationsInNamespace(Oid namespaceId, char relkind); static void expand_col_privileges(List *colnames, Oid table_oid, AclMode this_privileges, AclMode *col_privileges, *************** ExecuteGrantStmt(GrantStmt *stmt) *** 286,292 **** */ istmt.is_grant = stmt->is_grant; istmt.objtype = stmt->objtype; ! istmt.objects = objectNamesToOids(stmt->objtype, stmt->objects); /* all_privs to be filled below */ /* privileges to be filled below */ istmt.col_privs = NIL; /* may get filled below */ --- 288,297 ---- */ istmt.is_grant = stmt->is_grant; istmt.objtype = stmt->objtype; ! if (stmt->is_schema) ! istmt.objects = getNamespacesObjectsOids(stmt->objtype, stmt->objects); ! else ! istmt.objects = objectNamesToOids(stmt->objtype, stmt->objects); /* all_privs to be filled below */ /* privileges to be filled below */ istmt.col_privs = NIL; /* may get filled below */ *************** ExecuteGrantStmt(GrantStmt *stmt) *** 325,330 **** --- 330,336 ---- * the object type. */ case ACL_OBJECT_RELATION: + case ACL_OBJECT_VIEW: all_privileges = ACL_ALL_RIGHTS_RELATION | ACL_ALL_RIGHTS_SEQUENCE; errormsg = gettext_noop("invalid privilege type %s for relation"); break; *************** ExecuteGrantStmt(GrantStmt *stmt) *** 394,400 **** */ if (privnode->cols) { ! if (stmt->objtype != ACL_OBJECT_RELATION) ereport(ERROR, (errcode(ERRCODE_INVALID_GRANT_OPERATION), errmsg("column privileges are only valid for relations"))); --- 400,406 ---- */ if (privnode->cols) { ! if (stmt->objtype != ACL_OBJECT_RELATION && stmt->objtype != ACL_OBJECT_VIEW) ereport(ERROR, (errcode(ERRCODE_INVALID_GRANT_OPERATION), errmsg("column privileges are only valid for relations"))); *************** ExecGrantStmt_oids(InternalGrant *istmt) *** 431,436 **** --- 437,443 ---- switch (istmt->objtype) { case ACL_OBJECT_RELATION: + case ACL_OBJECT_VIEW: case ACL_OBJECT_SEQUENCE: ExecGrant_Relation(istmt); break; *************** objectNamesToOids(GrantObjectType objtyp *** 477,482 **** --- 484,490 ---- switch (objtype) { case ACL_OBJECT_RELATION: + case ACL_OBJECT_VIEW: case ACL_OBJECT_SEQUENCE: foreach(cell, objnames) { *************** objectNamesToOids(GrantObjectType objtyp *** 609,614 **** --- 617,756 ---- return objects; } + + /* + * getNamespacesObjectsOids + * + * Get all objects of a given type from specified schema list into an Oid list. + */ + static List * + getNamespacesObjectsOids(GrantObjectType objtype, List *nspnames) + { + List *objects = NIL; + ListCell *cell; + char *nspname; + Oid namespaceId; + + switch (objtype) + { + case ACL_OBJECT_RELATION: + foreach(cell, nspnames) + { + List *relations = NIL; + + nspname = strVal(lfirst(cell)); + namespaceId = LookupExplicitNamespace(nspname); + + relations = getRelationsInNamespace(namespaceId, RELKIND_RELATION); + + objects = list_union_ptr(relations, objects); + } + break; + case ACL_OBJECT_VIEW: + foreach(cell, nspnames) + { + List *relations = NIL; + + nspname = strVal(lfirst(cell)); + namespaceId = LookupExplicitNamespace(nspname); + + relations = getRelationsInNamespace(namespaceId, RELKIND_VIEW); + + objects = list_union_ptr(relations, objects); + } + break; + case ACL_OBJECT_SEQUENCE: + foreach(cell, nspnames) + { + List *relations = NIL; + + nspname = strVal(lfirst(cell)); + namespaceId = LookupExplicitNamespace(nspname); + + relations = getRelationsInNamespace(namespaceId, RELKIND_SEQUENCE); + + objects = list_union_ptr(relations, objects); + } + break; + case ACL_OBJECT_FUNCTION: + foreach(cell, nspnames) + { + ScanKeyData key[1]; + HeapScanDesc scan; + HeapTuple tuple; + Relation rel; + + nspname = strVal(lfirst(cell)); + namespaceId = LookupExplicitNamespace(nspname); + + ScanKeyInit(&key[0], + Anum_pg_proc_pronamespace, + BTEqualStrategyNumber, F_OIDEQ, + ObjectIdGetDatum(namespaceId)); + + rel = heap_open(ProcedureRelationId, AccessShareLock); + + scan = heap_beginscan(rel, SnapshotNow, 1, key); + + while ((tuple = heap_getnext(scan, ForwardScanDirection)) != NULL) + { + objects = lappend_oid(objects, HeapTupleGetOid(tuple)); + } + + heap_endscan(scan); + + heap_close(rel, AccessShareLock); + } + break; + default: + elog(ERROR, "unrecognized GrantStmt.objtype: %d", + (int) objtype); + } + + return objects; + } + + /* + * getRelationsInNamespace + * + * Return list of relations in given namespace filtered by relation kind + */ + static List * + getRelationsInNamespace(Oid namespaceId, char relkind) + { + List *relations = NIL; + ScanKeyData key[2]; + HeapScanDesc scan; + HeapTuple tuple; + Relation rel; + + ScanKeyInit(&key[0], + Anum_pg_class_relnamespace, + BTEqualStrategyNumber, F_OIDEQ, + ObjectIdGetDatum(namespaceId)); + + ScanKeyInit(&key[1], + Anum_pg_class_relkind, + BTEqualStrategyNumber, F_CHAREQ, + CharGetDatum(relkind)); + + rel = heap_open(RelationRelationId, AccessShareLock); + + scan = heap_beginscan(rel, SnapshotNow, 2, key); + + while ((tuple = heap_getnext(scan, ForwardScanDirection)) != NULL) + { + relations = lappend_oid(relations, HeapTupleGetOid(tuple)); + } + + heap_endscan(scan); + + heap_close(rel, AccessShareLock); + + return relations; + } + + /* * expand_col_privileges * *************** ExecGrant_Relation(InternalGrant *istmt) *** 912,918 **** * permissions. The OR of table and sequence permissions were already * checked. */ ! if (istmt->objtype == ACL_OBJECT_RELATION) { if (pg_class_tuple->relkind == RELKIND_SEQUENCE) { --- 1054,1060 ---- * permissions. The OR of table and sequence permissions were already * checked. */ ! if (istmt->objtype == ACL_OBJECT_RELATION || istmt->objtype == ACL_OBJECT_VIEW) { if (pg_class_tuple->relkind == RELKIND_SEQUENCE) { *************** ExecGrant_Relation(InternalGrant *istmt) *** 986,996 **** aclDatum = SysCacheGetAttr(RELOID, tuple, Anum_pg_class_relacl, &isNull); if (isNull) ! old_acl = acldefault(pg_class_tuple->relkind == RELKIND_SEQUENCE ? ! ACL_OBJECT_SEQUENCE : ACL_OBJECT_RELATION, ! ownerId); else old_acl = DatumGetAclPCopy(aclDatum); /* Need an extra copy of original rel ACL for column handling */ old_rel_acl = aclcopy(old_acl); --- 1128,1150 ---- aclDatum = SysCacheGetAttr(RELOID, tuple, Anum_pg_class_relacl, &isNull); if (isNull) ! { ! switch (pg_class_tuple->relkind) ! { ! case RELKIND_SEQUENCE: ! old_acl = acldefault(ACL_OBJECT_SEQUENCE, ownerId); ! break; ! case RELKIND_VIEW: ! old_acl = acldefault(ACL_OBJECT_VIEW, ownerId); ! break; ! default: ! old_acl = acldefault(ACL_OBJECT_RELATION, ownerId); ! } ! } else + { old_acl = DatumGetAclPCopy(aclDatum); + } /* Need an extra copy of original rel ACL for column handling */ old_rel_acl = aclcopy(old_acl); *************** pg_class_aclmask(Oid table_oid, Oid role *** 2434,2442 **** if (isNull) { /* No ACL, so build default ACL */ ! acl = acldefault(classForm->relkind == RELKIND_SEQUENCE ? ! ACL_OBJECT_SEQUENCE : ACL_OBJECT_RELATION, ! ownerId); aclDatum = (Datum) 0; } else --- 2588,2604 ---- if (isNull) { /* No ACL, so build default ACL */ ! switch (classForm->relkind) ! { ! case RELKIND_SEQUENCE: ! acl = acldefault(ACL_OBJECT_SEQUENCE, ownerId); ! break; ! case RELKIND_VIEW: ! acl = acldefault(ACL_OBJECT_VIEW, ownerId); ! break; ! default: ! acl = acldefault(ACL_OBJECT_RELATION, ownerId); ! } aclDatum = (Datum) 0; } else diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y index 9a45355..3bc5dc5 100644 *** a/src/backend/parser/gram.y --- b/src/backend/parser/gram.y *************** static bool QueryIsRule = FALSE; *** 98,103 **** --- 98,104 ---- typedef struct PrivTarget { GrantObjectType objtype; + bool is_schema; List *objs; } PrivTarget; *************** static TypeName *TableFuncTypeName(List *** 449,455 **** EXCLUDING EXCLUSIVE EXECUTE EXISTS EXPLAIN EXTERNAL EXTRACT FALSE_P FAMILY FETCH FIRST_P FLOAT_P FOLLOWING FOR FORCE FOREIGN FORWARD ! FREEZE FROM FULL FUNCTION GLOBAL GRANT GRANTED GREATEST GROUP_P --- 450,456 ---- EXCLUDING EXCLUSIVE EXECUTE EXISTS EXPLAIN EXTERNAL EXTRACT FALSE_P FAMILY FETCH FIRST_P FLOAT_P FOLLOWING FOR FORCE FOREIGN FORWARD ! FREEZE FROM FULL FUNCTION FUNCTIONS GLOBAL GRANT GRANTED GREATEST GROUP_P *************** static TypeName *TableFuncTypeName(List *** 487,499 **** RELATIVE_P RELEASE RENAME REPEATABLE REPLACE REPLICA RESET RESTART RESTRICT RETURNING RETURNS REVOKE RIGHT ROLE ROLLBACK ROW ROWS RULE ! SAVEPOINT SCHEMA SCROLL SEARCH SECOND_P SECURITY SELECT SEQUENCE SERIALIZABLE SERVER SESSION SESSION_USER SET SETOF SHARE SHOW SIMILAR SIMPLE SMALLINT SOME STABLE STANDALONE_P START STATEMENT STATISTICS STDIN STDOUT STORAGE STRICT_P STRIP_P SUBSTRING SUPERUSER_P SYMMETRIC SYSID SYSTEM_P ! TABLE TABLESPACE TEMP TEMPLATE TEMPORARY TEXT_P THEN TIME TIMESTAMP TO TRAILING TRANSACTION TREAT TRIGGER TRIM TRUE_P TRUNCATE TRUSTED TYPE_P --- 488,500 ---- RELATIVE_P RELEASE RENAME REPEATABLE REPLACE REPLICA RESET RESTART RESTRICT RETURNING RETURNS REVOKE RIGHT ROLE ROLLBACK ROW ROWS RULE ! SAVEPOINT SCHEMA SCROLL SEARCH SECOND_P SECURITY SELECT SEQUENCE SEQUENCES SERIALIZABLE SERVER SESSION SESSION_USER SET SETOF SHARE SHOW SIMILAR SIMPLE SMALLINT SOME STABLE STANDALONE_P START STATEMENT STATISTICS STDIN STDOUT STORAGE STRICT_P STRIP_P SUBSTRING SUPERUSER_P SYMMETRIC SYSID SYSTEM_P ! TABLE TABLES TABLESPACE TEMP TEMPLATE TEMPORARY TEXT_P THEN TIME TIMESTAMP TO TRAILING TRANSACTION TREAT TRIGGER TRIM TRUE_P TRUNCATE TRUSTED TYPE_P *************** static TypeName *TableFuncTypeName(List *** 501,507 **** UPDATE USER USING VACUUM VALID VALIDATOR VALUE_P VALUES VARCHAR VARIADIC VARYING ! VERBOSE VERSION_P VIEW VOLATILE WHEN WHERE WHITESPACE_P WINDOW WITH WITHOUT WORK WRAPPER WRITE --- 502,508 ---- UPDATE USER USING VACUUM VALID VALIDATOR VALUE_P VALUES VARCHAR VARIADIC VARYING ! VERBOSE VERSION_P VIEW VIEWS VOLATILE WHEN WHERE WHITESPACE_P WINDOW WITH WITHOUT WORK WRAPPER WRITE *************** GrantStmt: GRANT privileges ON privilege *** 4227,4232 **** --- 4228,4234 ---- n->is_grant = true; n->privileges = $2; n->objtype = ($4)->objtype; + n->is_schema = ($4)->is_schema; n->objects = ($4)->objs; n->grantees = $6; n->grant_option = $7; *************** RevokeStmt: *** 4243,4248 **** --- 4245,4251 ---- n->grant_option = false; n->privileges = $2; n->objtype = ($4)->objtype; + n->is_schema = ($4)->is_schema; n->objects = ($4)->objs; n->grantees = $6; n->behavior = $7; *************** RevokeStmt: *** 4256,4261 **** --- 4259,4265 ---- n->grant_option = true; n->privileges = $5; n->objtype = ($7)->objtype; + n->is_schema = ($7)->is_schema; n->objects = ($7)->objs; n->grantees = $9; n->behavior = $10; *************** privilege_target: *** 4338,4343 **** --- 4342,4348 ---- { PrivTarget *n = (PrivTarget *) palloc(sizeof(PrivTarget)); n->objtype = ACL_OBJECT_RELATION; + n->is_schema = FALSE; n->objs = $1; $$ = n; } *************** privilege_target: *** 4345,4350 **** --- 4350,4364 ---- { PrivTarget *n = (PrivTarget *) palloc(sizeof(PrivTarget)); n->objtype = ACL_OBJECT_RELATION; + n->is_schema = FALSE; + n->objs = $2; + $$ = n; + } + | VIEW qualified_name_list + { + PrivTarget *n = (PrivTarget *) palloc(sizeof(PrivTarget)); + n->objtype = ACL_OBJECT_VIEW; + n->is_schema = FALSE; n->objs = $2; $$ = n; } *************** privilege_target: *** 4352,4357 **** --- 4366,4372 ---- { PrivTarget *n = (PrivTarget *) palloc(sizeof(PrivTarget)); n->objtype = ACL_OBJECT_SEQUENCE; + n->is_schema = FALSE; n->objs = $2; $$ = n; } *************** privilege_target: *** 4359,4364 **** --- 4374,4380 ---- { PrivTarget *n = (PrivTarget *) palloc(sizeof(PrivTarget)); n->objtype = ACL_OBJECT_FDW; + n->is_schema = FALSE; n->objs = $4; $$ = n; } *************** privilege_target: *** 4366,4371 **** --- 4382,4388 ---- { PrivTarget *n = (PrivTarget *) palloc(sizeof(PrivTarget)); n->objtype = ACL_OBJECT_FOREIGN_SERVER; + n->is_schema = FALSE; n->objs = $3; $$ = n; } *************** privilege_target: *** 4373,4378 **** --- 4390,4396 ---- { PrivTarget *n = (PrivTarget *) palloc(sizeof(PrivTarget)); n->objtype = ACL_OBJECT_FUNCTION; + n->is_schema = FALSE; n->objs = $2; $$ = n; } *************** privilege_target: *** 4380,4385 **** --- 4398,4404 ---- { PrivTarget *n = (PrivTarget *) palloc(sizeof(PrivTarget)); n->objtype = ACL_OBJECT_DATABASE; + n->is_schema = FALSE; n->objs = $2; $$ = n; } *************** privilege_target: *** 4387,4392 **** --- 4406,4412 ---- { PrivTarget *n = (PrivTarget *) palloc(sizeof(PrivTarget)); n->objtype = ACL_OBJECT_LANGUAGE; + n->is_schema = FALSE; n->objs = $2; $$ = n; } *************** privilege_target: *** 4394,4399 **** --- 4414,4420 ---- { PrivTarget *n = (PrivTarget *) palloc(sizeof(PrivTarget)); n->objtype = ACL_OBJECT_NAMESPACE; + n->is_schema = FALSE; n->objs = $2; $$ = n; } *************** privilege_target: *** 4401,4409 **** --- 4422,4463 ---- { PrivTarget *n = (PrivTarget *) palloc(sizeof(PrivTarget)); n->objtype = ACL_OBJECT_TABLESPACE; + n->is_schema = FALSE; n->objs = $2; $$ = n; } + | ALL TABLES IN_P name_list + { + PrivTarget *n = (PrivTarget *) palloc(sizeof(PrivTarget)); + n->objtype = ACL_OBJECT_RELATION; + n->is_schema = TRUE; + n->objs = $4; + $$ = n; + } + | ALL VIEWS IN_P name_list + { + PrivTarget *n = (PrivTarget *) palloc(sizeof(PrivTarget)); + n->objtype = ACL_OBJECT_VIEW; + n->is_schema = TRUE; + n->objs = $4; + $$ = n; + } + | ALL SEQUENCES IN_P name_list + { + PrivTarget *n = (PrivTarget *) palloc(sizeof(PrivTarget)); + n->objtype = ACL_OBJECT_SEQUENCE; + n->is_schema = TRUE; + n->objs = $4; + $$ = n; + } + | ALL FUNCTIONS IN_P name_list + { + PrivTarget *n = (PrivTarget *) palloc(sizeof(PrivTarget)); + n->objtype = ACL_OBJECT_FUNCTION; + n->is_schema = TRUE; + n->objs = $4; + $$ = n; + } ; *************** unreserved_keyword: *** 10212,10217 **** --- 10266,10272 ---- | FORCE | FORWARD | FUNCTION + | FUNCTIONS | GLOBAL | GRANTED | HANDLER *************** unreserved_keyword: *** 10321,10326 **** --- 10376,10382 ---- | SECOND_P | SECURITY | SEQUENCE + | SEQUENCES | SERIALIZABLE | SERVER | SESSION *************** unreserved_keyword: *** 10341,10346 **** --- 10397,10403 ---- | SUPERUSER_P | SYSID | SYSTEM_P + | TABLES | TABLESPACE | TEMP | TEMPLATE *************** unreserved_keyword: *** 10365,10370 **** --- 10422,10428 ---- | VARYING | VERSION_P | VIEW + | VIEWS | VOLATILE | WHITESPACE_P | WITHOUT diff --git a/src/backend/utils/adt/acl.c b/src/backend/utils/adt/acl.c index 334823b..ddd92e7 100644 *** a/src/backend/utils/adt/acl.c --- b/src/backend/utils/adt/acl.c *************** acldefault(GrantObjectType objtype, Oid *** 609,614 **** --- 609,615 ---- owner_default = ACL_NO_RIGHTS; break; case ACL_OBJECT_RELATION: + case ACL_OBJECT_VIEW: world_default = ACL_NO_RIGHTS; owner_default = ACL_ALL_RIGHTS_RELATION; break; diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h index 71c864a..3c79a1c 100644 *** a/src/include/nodes/parsenodes.h --- b/src/include/nodes/parsenodes.h *************** typedef struct AlterDomainStmt *** 1180,1186 **** typedef enum GrantObjectType { ACL_OBJECT_COLUMN, /* column */ ! ACL_OBJECT_RELATION, /* table, view */ ACL_OBJECT_SEQUENCE, /* sequence */ ACL_OBJECT_DATABASE, /* database */ ACL_OBJECT_FDW, /* foreign-data wrapper */ --- 1180,1186 ---- typedef enum GrantObjectType { ACL_OBJECT_COLUMN, /* column */ ! ACL_OBJECT_RELATION, /* table */ ACL_OBJECT_SEQUENCE, /* sequence */ ACL_OBJECT_DATABASE, /* database */ ACL_OBJECT_FDW, /* foreign-data wrapper */ *************** typedef enum GrantObjectType *** 1188,1194 **** ACL_OBJECT_FUNCTION, /* function */ ACL_OBJECT_LANGUAGE, /* procedural language */ ACL_OBJECT_NAMESPACE, /* namespace */ ! ACL_OBJECT_TABLESPACE /* tablespace */ } GrantObjectType; typedef struct GrantStmt --- 1188,1195 ---- ACL_OBJECT_FUNCTION, /* function */ ACL_OBJECT_LANGUAGE, /* procedural language */ ACL_OBJECT_NAMESPACE, /* namespace */ ! ACL_OBJECT_TABLESPACE, /* tablespace */ ! ACL_OBJECT_VIEW, /* view */ } GrantObjectType; typedef struct GrantStmt *************** typedef struct GrantStmt *** 1196,1201 **** --- 1197,1204 ---- NodeTag type; bool is_grant; /* true = GRANT, false = REVOKE */ GrantObjectType objtype; /* kind of object being operated on */ + bool is_schema; /* if true we want all objects + * of objtype in schema */ List *objects; /* list of RangeVar nodes, FuncWithArgs nodes, * or plain names (as Value strings) */ List *privileges; /* list of AccessPriv nodes */ diff --git a/src/include/parser/kwlist.h b/src/include/parser/kwlist.h index 67e9cb4..a6ae56c 100644 *** a/src/include/parser/kwlist.h --- b/src/include/parser/kwlist.h *************** PG_KEYWORD("freeze", FREEZE, TYPE_FUNC_N *** 163,168 **** --- 163,169 ---- PG_KEYWORD("from", FROM, RESERVED_KEYWORD) PG_KEYWORD("full", FULL, TYPE_FUNC_NAME_KEYWORD) PG_KEYWORD("function", FUNCTION, UNRESERVED_KEYWORD) + PG_KEYWORD("functions", FUNCTIONS, UNRESERVED_KEYWORD) PG_KEYWORD("global", GLOBAL, UNRESERVED_KEYWORD) PG_KEYWORD("grant", GRANT, RESERVED_KEYWORD) PG_KEYWORD("granted", GRANTED, UNRESERVED_KEYWORD) *************** PG_KEYWORD("second", SECOND_P, UNRESERVE *** 328,333 **** --- 329,335 ---- PG_KEYWORD("security", SECURITY, UNRESERVED_KEYWORD) PG_KEYWORD("select", SELECT, RESERVED_KEYWORD) PG_KEYWORD("sequence", SEQUENCE, UNRESERVED_KEYWORD) + PG_KEYWORD("sequences", SEQUENCES, UNRESERVED_KEYWORD) PG_KEYWORD("serializable", SERIALIZABLE, UNRESERVED_KEYWORD) PG_KEYWORD("server", SERVER, UNRESERVED_KEYWORD) PG_KEYWORD("session", SESSION, UNRESERVED_KEYWORD) *************** PG_KEYWORD("symmetric", SYMMETRIC, RESER *** 356,361 **** --- 358,364 ---- PG_KEYWORD("sysid", SYSID, UNRESERVED_KEYWORD) PG_KEYWORD("system", SYSTEM_P, UNRESERVED_KEYWORD) PG_KEYWORD("table", TABLE, RESERVED_KEYWORD) + PG_KEYWORD("tables", TABLES, UNRESERVED_KEYWORD) PG_KEYWORD("tablespace", TABLESPACE, UNRESERVED_KEYWORD) PG_KEYWORD("temp", TEMP, UNRESERVED_KEYWORD) PG_KEYWORD("template", TEMPLATE, UNRESERVED_KEYWORD) *************** PG_KEYWORD("varying", VARYING, UNRESERVE *** 396,401 **** --- 399,405 ---- PG_KEYWORD("verbose", VERBOSE, TYPE_FUNC_NAME_KEYWORD) PG_KEYWORD("version", VERSION_P, UNRESERVED_KEYWORD) PG_KEYWORD("view", VIEW, UNRESERVED_KEYWORD) + PG_KEYWORD("views", VIEWS, UNRESERVED_KEYWORD) PG_KEYWORD("volatile", VOLATILE, UNRESERVED_KEYWORD) PG_KEYWORD("when", WHEN, RESERVED_KEYWORD) PG_KEYWORD("where", WHERE, RESERVED_KEYWORD) diff --git a/src/test/regress/expected/privileges.out b/src/test/regress/expected/privileges.out index a17ff59..043c0f3 100644 *** a/src/test/regress/expected/privileges.out --- b/src/test/regress/expected/privileges.out *************** SELECT has_table_privilege('regressuser1 *** 815,820 **** --- 815,849 ---- t (1 row) + -- Grant on all objects of given type in a schema + RESET SESSION AUTHORIZATION; + REVOKE ALL ON ALL TABLES IN public FROM regressuser1; + SELECT has_table_privilege('regressuser1', 'atest1', 'SELECT'); -- false + has_table_privilege + --------------------- + f + (1 row) + + REVOKE ALL ON ALL FUNCTIONS IN public FROM regressuser1; + SET SESSION AUTHORIZATION regressuser1; + SELECT testfunc2(5); -- fail + ERROR: permission denied for function testfunc2 + RESET SESSION AUTHORIZATION; + GRANT ALL ON ALL TABLES IN public TO regressuser1; + SELECT has_table_privilege('regressuser1', 'atest2', 'SELECT'); -- true + has_table_privilege + --------------------- + t + (1 row) + + GRANT ALL ON ALL FUNCTIONS IN public TO regressuser1; + SET SESSION AUTHORIZATION regressuser1; + SELECT testfunc2(5); -- ok + testfunc2 + ----------- + 15 + (1 row) + -- clean up \c DROP FUNCTION testfunc2(int); *************** DROP TABLE atestp2; *** 839,844 **** --- 868,875 ---- DROP GROUP regressgroup1; DROP GROUP regressgroup2; REVOKE USAGE ON LANGUAGE sql FROM regressuser1; + REVOKE ALL ON ALL TABLES IN public FROM regressuser1; + REVOKE ALL ON ALL FUNCTIONS IN public FROM regressuser1; DROP USER regressuser1; DROP USER regressuser2; DROP USER regressuser3; diff --git a/src/test/regress/sql/privileges.sql b/src/test/regress/sql/privileges.sql index 5aa1012..e574c4d 100644 *** a/src/test/regress/sql/privileges.sql --- b/src/test/regress/sql/privileges.sql *************** SELECT has_table_privilege('regressuser3 *** 469,474 **** --- 469,500 ---- SELECT has_table_privilege('regressuser1', 'atest4', 'SELECT WITH GRANT OPTION'); -- true + -- Grant on all objects of given type in a schema + + RESET SESSION AUTHORIZATION; + + REVOKE ALL ON ALL TABLES IN public FROM regressuser1; + + SELECT has_table_privilege('regressuser1', 'atest1', 'SELECT'); -- false + + REVOKE ALL ON ALL FUNCTIONS IN public FROM regressuser1; + + SET SESSION AUTHORIZATION regressuser1; + + SELECT testfunc2(5); -- fail + + RESET SESSION AUTHORIZATION; + + GRANT ALL ON ALL TABLES IN public TO regressuser1; + + SELECT has_table_privilege('regressuser1', 'atest2', 'SELECT'); -- true + + GRANT ALL ON ALL FUNCTIONS IN public TO regressuser1; + + SET SESSION AUTHORIZATION regressuser1; + + SELECT testfunc2(5); -- ok + -- clean up \c *************** DROP GROUP regressgroup1; *** 497,502 **** --- 523,530 ---- DROP GROUP regressgroup2; REVOKE USAGE ON LANGUAGE sql FROM regressuser1; + REVOKE ALL ON ALL TABLES IN public FROM regressuser1; + REVOKE ALL ON ALL FUNCTIONS IN public FROM regressuser1; DROP USER regressuser1; DROP USER regressuser2; DROP USER regressuser3;
On Wednesday 17 June 2009 11:29:10 Petr Jelinek wrote: > The patch allows "GRANT ON ALL TABLES/VIEWS/FUNCTIONS/SEQUENCES IN > schemaname, schemaname2 TO username" and same thing for REVOKE. > Words TABLES, VIEWS, FUNCTIONS and SEQUENCES were added as unreserved > keywords. Unfortunately I was unable to create syntax with optional > SCHEMA keyword after IN (shift/reduce conflicts), if it's needed maybe > somebody with better bison knowledge might add it. I think you should design this with a bit wider scope. Instead of just "all tables in this schema", think "all tables satisfying some condition". It has been requested, for example, to be able to grant on all tables that match a pattern. > Also since this patch introduces VIEWS as object with grantable > privileges, I added GRANT ON VIEW foo syntax which is more or less > synonymous to GRANT ON TABLE foo syntax. It felt weird to have GRANT ON > ALL VIEWS but not GRANT ON VIEW. As far as GRANT is concerned, a view is a table, so I would omit the VIEW/VIEWS stuff completely.
Peter, * Peter Eisentraut (peter_e@gmx.net) wrote: > > Also since this patch introduces VIEWS as object with grantable > > privileges, I added GRANT ON VIEW foo syntax which is more or less > > synonymous to GRANT ON TABLE foo syntax. It felt weird to have GRANT ON > > ALL VIEWS but not GRANT ON VIEW. > > As far as GRANT is concerned, a view is a table, so I would omit the > VIEW/VIEWS stuff completely. I would disagree with this. While an explicit GRANT doesn't need to care, because you can't have a view and a table with the same name, I feel *users* (like me) make a distinction there and may want to limit the grant to just views or just tables. What we do here will also impact the DefaultACL system that I'm working on since I think we should be consistant between these two systems. http://wiki.postgresql.org/wiki/DefaultACL I don't like the idea that a 'GRANT ALL' would actually change default ACLs for a schema though. These are two separate and distinct things- one is implementing a change to existing objects, the other is setting a default for new objects. Mixing them would lead to confusion. Thanks, Stephen
Peter Eisentraut <peter_e@gmx.net> writes: > I think you should design this with a bit wider scope. Instead of just "all > tables in this schema", think "all tables satisfying some condition". It has > been requested, for example, to be able to grant on all tables that match a > pattern. I'm against that. Functionality of that sort is available now if you really need it (write a plpgsql loop around an EXECUTE) and it's fairly hard to see a clean syntax that is significantly more general than "GRANT ON schema.*". In particular I strongly advise against getting into supporting user-defined predicates in GRANT. There are good reasons for not having utility statements evaluate random expressions. regards, tom lane
Petr, * Petr Jelinek (pjmodos@pjmodos.net) wrote: > So, here is the first version of the patch. Neat, thanks! Some initial comments: You should read through this: http://wiki.postgresql.org/wiki/Submitting_a_Patch First big thing is that the patch should be a context diff. I would also recommend you put it up on the CommitFest wiki if it's not there yet. You might also write up a wiki page on it and link to it from the 8.5 WIP section under http://wiki.postgresql.org/wiki/Developer_and_Contributor_Resources The http://wiki.postgresql.org/wiki/Developer_FAQ can also help if you havn't checked it out yet. > It includes functionality itself, simple regression test and also very > simple documentation. Excellent! > Any comments/suggestions are welcome (I especially wonder if the use of > list_union_ptr is acceptable). I'll try to take a look at the actual patch in more detail later this week. Thanks! Stephen
Stephen Frost wrote: > I don't like the idea that a 'GRANT ALL' would actually change default > ACLs for a schema though. These are two separate and distinct things- > one is implementing a change to existing objects, the other is setting a > default for new objects. Mixing them would lead to confusion. > It doesn't. I stated that I am not implementing the second part of the TODO item in my first email specifically for this reason (the second part was GRANT ON NEW TABLES). -- Regards Petr Jelinek (PJMODOS)
Stephen Frost wrote: > http://wiki.postgresql.org/wiki/Submitting_a_Patch > > First big thing is that the patch should be a context diff. I would > It is context diff, at least I think so, I followed the instructions on wiki on how to make context patch from git repo. > also recommend you put it up on the CommitFest wiki if it's not there > yet. You might also write up a wiki page on it and link to it from the > 8.5 WIP section under > http://wiki.postgresql.org/wiki/Developer_and_Contributor_Resources > Will do. > I'll try to take a look at the actual patch in more detail later this > week. > Thanks. -- Regards Petr Jelinek (PJMODOS)
* Petr Jelinek (pjmodos@pjmodos.net) wrote: > Stephen Frost wrote: >> I don't like the idea that a 'GRANT ALL' would actually change default >> ACLs for a schema though. These are two separate and distinct things- >> one is implementing a change to existing objects, the other is setting a >> default for new objects. Mixing them would lead to confusion. > > It doesn't. I stated that I am not implementing the second part of the > TODO item in my first email specifically for this reason (the second > part was GRANT ON NEW TABLES). Right.. I was arguing against a few folks who had mentioned they'd like to see that on IRC and in the past, not against your implementation. Thanks, Stephen
On Wednesday 17 June 2009 17:15:04 Tom Lane wrote: > Peter Eisentraut <peter_e@gmx.net> writes: > > I think you should design this with a bit wider scope. Instead of just > > "all tables in this schema", think "all tables satisfying some > > condition". It has been requested, for example, to be able to grant on > > all tables that match a pattern. > > I'm against that. Functionality of that sort is available now if you > really need it (write a plpgsql loop around an EXECUTE) and it's fairly > hard to see a clean syntax that is significantly more general than > "GRANT ON schema.*". In particular I strongly advise against getting > into supporting user-defined predicates in GRANT. There are good > reasons for not having utility statements evaluate random expressions. Why don't we tell people to write a plpgsql loop for the schema.* case as well? I haven't seen any evidence that the schema.* case is more common than other bulk DDL cases like "matches pattern" or "owned by $user" or "grant on all functions that are not security definer" etc.
Peter Eisentraut <peter_e@gmx.net> writes: > Why don't we tell people to write a plpgsql loop for the schema.* case as > well? Indeed, why not? This all seems much more like gilding the lily than delivering useful new capability. The default-ACL stuff that Stephen is working on seems far more important in practice. regards, tom lane
* Petr Jelinek (pjmodos@pjmodos.net) wrote: > It is context diff, at least I think so, I followed the instructions on > wiki on how to make context patch from git repo. err, sorry, tbh I just looked at the 'diff --git' line and didn't see any '-c'.. Trying to do too much at one time, I'm afraid. :) Thanks, Stephen
Peter Eisentraut wrote: > I think you should design this with a bit wider scope. Instead of just "all > tables in this schema", think "all tables satisfying some condition". It has > been requested, for example, to be able to grant on all tables that match a > pattern. > Well, that's certainly possible to do. But I am not sure what kind of conditions (besides the name), nor I don't see any sane grammar for this (maybe something like GRANT SELECT ON TABLE WHERE NAME LIKE '%foo' but that's far to weird). That all tables in this schema thing was agreed on on this mailing list and put on TODO so I thought it's something people want in this form (I know I needed it myself). > As far as GRANT is concerned, a view is a table, so I would omit the > VIEW/VIEWS stuff completely. > This maybe true for underlying implementation and for granting permissions to a single object, but you might want to grant select on all views without granting it to all tables in the schema. And as I said having VIEWS and not VIEW just seems weird. Also I don't see why you would want to add possibility of specifying stricter conditions for objects and at the same time remove possibility of distinguishing between tables and views. -- Regards Petr Jelinek (PJMODOS)
Tom Lane erote: <blockquote cite="mid:26370.1245250052@sss.pgh.pa.us" type="cite"><pre wrap="">Peter Eisentraut <a class="moz-txt-link-rfc2396E"href="mailto:peter_e@gmx.net"><peter_e@gmx.net></a> writes: </pre><blockquote type="cite"><prewrap="">Why don't we tell people to write a plpgsql loop for the schema.* case as well? </pre></blockquote><pre wrap=""> Indeed, why not? This all seems much more like gilding the lily than delivering useful new capability. The default-ACL stuff that Stephen is working on seems far more important in practice. </pre></blockquote><br /> I agree that Default ACLs are more importantand I already offered Stephen help on that. But I've seen countless requests for granting on all tables to a userand I already got some positive feedback outside of the list, so I believe there is demand for this. Also to paraphraseyou Tom, by that logic you can tell people to write half of administration functionality as plpgsql functions.<br/><br /><pre class="moz-signature" cols="72">-- Regards Petr Jelinek (PJMODOS)</pre>
2009/6/17 Petr Jelinek <pjmodos@pjmodos.net>: > I agree that Default ACLs are more important and I already offered Stephen > help on that. But I've seen countless requests for granting on all tables to > a user and I already got some positive feedback outside of the list, so I > believe there is demand for this. Also to paraphrase you Tom, by that logic > you can tell people to write half of administration functionality as plpgsql > functions. Indeed. How to do default ACLs and wildcards for GRANT is by far the most common question asked by our customers. And they don't understand why it's not by default in PostgreSQL. Installing a script/function for that on every database is just painful. -- Guillaume
Isn't the answer to grant permissions to a role and then just put people in that role? -- Greg On 17 Jun 2009, at 17:25, Guillaume Smet <guillaume.smet@gmail.com> wrote: > 2009/6/17 Petr Jelinek <pjmodos@pjmodos.net>: >> I agree that Default ACLs are more important and I already offered >> Stephen >> help on that. But I've seen countless requests for granting on all >> tables to >> a user and I already got some positive feedback outside of the >> list, so I >> believe there is demand for this. Also to paraphrase you Tom, by >> that logic >> you can tell people to write half of administration functionality >> as plpgsql >> functions. > > Indeed. > > How to do default ACLs and wildcards for GRANT is by far the most > common question asked by our customers. And they don't understand why > it's not by default in PostgreSQL. > > Installing a script/function for that on every database is just > painful. > > -- > Guillaume > > -- > Sent via pgsql-hackers mailing list (pgsql-hackers@postgresql.org) > To make changes to your subscription: > http://www.postgresql.org/mailpref/pgsql-hackers
Greg Stark wrote: > Isn't the answer to grant permissions to a role and then just put > people in that role? > Still have to give permissions at least to that role. -- Regards Petr Jelinek (PJMODOS)
On Wed, Jun 17, 2009 at 12:25 PM, Guillaume Smet<guillaume.smet@gmail.com> wrote: > 2009/6/17 Petr Jelinek <pjmodos@pjmodos.net>: >> I agree that Default ACLs are more important and I already offered Stephen >> help on that. But I've seen countless requests for granting on all tables to >> a user and I already got some positive feedback outside of the list, so I >> believe there is demand for this. Also to paraphrase you Tom, by that logic >> you can tell people to write half of administration functionality as plpgsql >> functions. > > Indeed. > > How to do default ACLs and wildcards for GRANT is by far the most > common question asked by our customers. And they don't understand why > it's not by default in PostgreSQL. > > Installing a script/function for that on every database is just painful. It's not just GRANT, either. I have a script that synchronizes data from <other database product> into PostgreSQL. It runs out of cron. I actually had to set it up so that it counts the total number of rows that it has inserted and fires of an ANALYZE when it hits a certain threshold (that might not be necessary with autovacuum, but this is 8.1); otherwise, the statistics can get so far from reality that the sync script never finishes, because the later stages of the sync query local data modified by earlier stages of the sync. This is not a joke; when there are heavy data modifications, the script MUST fire an ANALYZE midway through to complete in a reasonable amount of time. Now it just so happens that this application runs inside its own schema, and that it doesn't have permission to vacuum any of the other schemas, including the catalog tables. So what do you think happens when it kicks off an ANALYZE? A huge pile of warning messages. Now, since I've been reading pgsql-hackers religiously for a year now, I know that it's very easy to solve this problem by writing a table to issue a query against pg_class and then use quote_ident() to build up a query that we can EXECUTE from within a pl/pgsql loop. However, I certainly didn't know how to do that when I wrote the script two and a half years ago, at which time I had only about six years of experience with the product. Before I started reading -hackers, I relied on reading the fine manual: http://www.postgresql.org/docs/8.3/static/sql-analyze.html ...which doesn't describe how to do this. So I didn't know. But if the file manual had included the syntax "ANALYZE SCHEMA blat", I certainly would have used it, and thus avoided getting 10 emails a week from my cron job for the past two-and-half years. What to do about wildcards is a stickier wicket, and maybe we need to decide that first, but I really don't think we should be discouraging anyone from investigating this stuff and trying to come up with good solutions. There will always be some people for whom a custom PL/pgsql function that directly accesses the catalog tables is the only workable answer, but we can make PostgreSQL a whole lot easier to use by reducing the need to do that for simple cases. ...Robert
On Wednesday 17 June 2009 20:27:20 Robert Haas wrote: > What to do about wildcards is a stickier wicket, and maybe we need to > decide that first, but I really don't think we should be discouraging > anyone from investigating this stuff and trying to come up with good > solutions. There will always be some people for whom a custom > PL/pgsql function that directly accesses the catalog tables is the > only workable answer, but we can make PostgreSQL a whole lot easier to > use by reducing the need to do that for simple cases. I'm all for investigating it. I just have my doubts that "grant on all tables in schema X" is a sufficiently general use case, even if you only concentrate on the simple cases.
--On Mittwoch, Juni 17, 2009 16:44:53 +0300 Peter Eisentraut <peter_e@gmx.net> wrote: > I think you should design this with a bit wider scope. Instead of just > "all tables in this schema", think "all tables satisfying some > condition". It has been requested, for example, to be able to grant on > all tables that match a pattern. > My experience shows that having such a thing is often leading to "bad practices". People tend to grant everything to every login role instead of using an intelligent role privilege mechanism. MySQL for example has such wildcards (using '_' and '%' wildcard patterns), which often confuses people when having such characters in their table/database names (of course, i forgot to escape them more than once). The unpredictable results of messing up a complete schema when using a broken pattern expression is going to reduce the usefulness of such a feature, i think. >> Also since this patch introduces VIEWS as object with grantable >> privileges, I added GRANT ON VIEW foo syntax which is more or less >> synonymous to GRANT ON TABLE foo syntax. It felt weird to have GRANT ON >> ALL VIEWS but not GRANT ON VIEW. > > As far as GRANT is concerned, a view is a table, so I would omit the > VIEW/VIEWS stuff completely. We have ALTER VIEW now, so why don't implement the same synonym for GRANT? -- Thanks Bernd
Petr Jelinek wrote: > So, here is the first version of the patch. Attached is v2 with slightly improved code, nothing has changed feature-wise. -- Regards Petr Jelinek (PJMODOS) diff --git a/doc/src/sgml/ref/grant.sgml b/doc/src/sgml/ref/grant.sgml index bf963b8..7ddbd25 100644 *** a/doc/src/sgml/ref/grant.sgml --- b/doc/src/sgml/ref/grant.sgml *************** PostgreSQL documentation *** 23,39 **** <synopsis> GRANT { { SELECT | INSERT | UPDATE | DELETE | TRUNCATE | REFERENCES | TRIGGER } [,...] | ALL [ PRIVILEGES ] } ! ON [ TABLE ] <replaceable class="PARAMETER">tablename</replaceable> [, ...] TO { [ GROUP ] <replaceable class="PARAMETER">rolename</replaceable> | PUBLIC } [, ...] [ WITH GRANT OPTION ] GRANT { { SELECT | INSERT | UPDATE | REFERENCES } ( <replaceable class="PARAMETER">column</replaceable> [, ...] ) [,...] | ALL [ PRIVILEGES ] ( <replaceable class="PARAMETER">column</replaceable> [, ...] ) } ! ON [ TABLE ] <replaceable class="PARAMETER">tablename</replaceable> [, ...] TO { [ GROUP ] <replaceable class="PARAMETER">rolename</replaceable> | PUBLIC } [, ...] [ WITH GRANT OPTION ] GRANT { { USAGE | SELECT | UPDATE } [,...] | ALL [ PRIVILEGES ] } ! ON SEQUENCE <replaceable class="PARAMETER">sequencename</replaceable> [, ...] TO { [ GROUP ] <replaceable class="PARAMETER">rolename</replaceable> | PUBLIC } [, ...] [ WITH GRANT OPTION ] GRANT { { CREATE | CONNECT | TEMPORARY | TEMP } [,...] | ALL [ PRIVILEGES ] } --- 23,41 ---- <synopsis> GRANT { { SELECT | INSERT | UPDATE | DELETE | TRUNCATE | REFERENCES | TRIGGER } [,...] | ALL [ PRIVILEGES ] } ! ON { { [ TABLE | VIEW ] <replaceable class="PARAMETER">tablename</replaceable> [, ...] } ! | ALL [ TABLES | VIEWS ] IN <replaceable>schemaname</replaceable> [, ...] } TO { [ GROUP ] <replaceable class="PARAMETER">rolename</replaceable> | PUBLIC } [, ...] [ WITH GRANT OPTION ] GRANT { { SELECT | INSERT | UPDATE | REFERENCES } ( <replaceable class="PARAMETER">column</replaceable> [, ...] ) [,...] | ALL [ PRIVILEGES ] ( <replaceable class="PARAMETER">column</replaceable> [, ...] ) } ! ON [ TABLE | VIEW ] <replaceable class="PARAMETER">tablename</replaceable> [, ...] TO { [ GROUP ] <replaceable class="PARAMETER">rolename</replaceable> | PUBLIC } [, ...] [ WITH GRANT OPTION ] GRANT { { USAGE | SELECT | UPDATE } [,...] | ALL [ PRIVILEGES ] } ! ON { SEQUENCE <replaceable class="PARAMETER">sequencename</replaceable> [, ...] ! | ALL SEQUENCES IN <replaceable>schemaname</replaceable> [, ...] } TO { [ GROUP ] <replaceable class="PARAMETER">rolename</replaceable> | PUBLIC } [, ...] [ WITH GRANT OPTION ] GRANT { { CREATE | CONNECT | TEMPORARY | TEMP } [,...] | ALL [ PRIVILEGES ] } *************** GRANT { USAGE | ALL [ PRIVILEGES ] } *** 49,55 **** TO { [ GROUP ] <replaceable class="PARAMETER">rolename</replaceable> | PUBLIC } [, ...] [ WITH GRANT OPTION ] GRANT { EXECUTE | ALL [ PRIVILEGES ] } ! ON FUNCTION <replaceable>funcname</replaceable> ( [ [ <replaceable class="parameter">argmode</replaceable> ] [ <replaceableclass="parameter">argname</replaceable> ] <replaceable class="parameter">argtype</replaceable> [, ...] ] ) [,...] TO { [ GROUP ] <replaceable class="PARAMETER">rolename</replaceable> | PUBLIC } [, ...] [ WITH GRANT OPTION ] GRANT { USAGE | ALL [ PRIVILEGES ] } --- 51,58 ---- TO { [ GROUP ] <replaceable class="PARAMETER">rolename</replaceable> | PUBLIC } [, ...] [ WITH GRANT OPTION ] GRANT { EXECUTE | ALL [ PRIVILEGES ] } ! ON { FUNCTION <replaceable>funcname</replaceable> ( [ [ <replaceable class="parameter">argmode</replaceable> ] [ <replaceableclass="parameter">argname</replaceable> ] <replaceable class="parameter">argtype</replaceable> [, ...] ] ) [,...] ! | ALL FUNCTIONS IN <replaceable>schemaname</replaceable> [, ...] } TO { [ GROUP ] <replaceable class="PARAMETER">rolename</replaceable> | PUBLIC } [, ...] [ WITH GRANT OPTION ] GRANT { USAGE | ALL [ PRIVILEGES ] } *************** GRANT <replaceable class="PARAMETER">rol *** 143,148 **** --- 146,158 ---- </para> <para> + There is also the posibility of granting permissions to all objects of + given type inside one or multiple schemas. This functionality is supported + for tables, views, sequences and functions and can done by using + ALL TABLES IN schemanema syntax in place of object name. + </para> + + <para> The possible privileges are: <variablelist> diff --git a/doc/src/sgml/ref/revoke.sgml b/doc/src/sgml/ref/revoke.sgml index 8d62580..ac0905f 100644 *** a/doc/src/sgml/ref/revoke.sgml --- b/doc/src/sgml/ref/revoke.sgml *************** PostgreSQL documentation *** 24,44 **** REVOKE [ GRANT OPTION FOR ] { { SELECT | INSERT | UPDATE | DELETE | TRUNCATE | REFERENCES | TRIGGER } [,...] | ALL [ PRIVILEGES ] } ! ON [ TABLE ] <replaceable class="PARAMETER">tablename</replaceable> [, ...] FROM { [ GROUP ] <replaceable class="PARAMETER">rolename</replaceable> | PUBLIC } [, ...] [ CASCADE | RESTRICT ] REVOKE [ GRANT OPTION FOR ] { { SELECT | INSERT | UPDATE | REFERENCES } ( <replaceable class="PARAMETER">column</replaceable> [, ...] ) [,...] | ALL [ PRIVILEGES ] ( <replaceable class="PARAMETER">column</replaceable> [, ...] ) } ! ON [ TABLE ] <replaceable class="PARAMETER">tablename</replaceable> [, ...] FROM { [ GROUP ] <replaceable class="PARAMETER">rolename</replaceable> | PUBLIC } [, ...] [ CASCADE | RESTRICT ] REVOKE [ GRANT OPTION FOR ] { { USAGE | SELECT | UPDATE } [,...] | ALL [ PRIVILEGES ] } ! ON SEQUENCE <replaceable class="PARAMETER">sequencename</replaceable> [, ...] FROM { [ GROUP ] <replaceable class="PARAMETER">rolename</replaceable> | PUBLIC } [, ...] [ CASCADE | RESTRICT ] --- 24,46 ---- REVOKE [ GRANT OPTION FOR ] { { SELECT | INSERT | UPDATE | DELETE | TRUNCATE | REFERENCES | TRIGGER } [,...] | ALL [ PRIVILEGES ] } ! ON { { [ TABLE | VIEW ] <replaceable class="PARAMETER">tablename</replaceable> [, ...] } ! | ALL [ TABLES | VIEWS ] IN <replaceable>schemaname</replaceable> [, ...] } FROM { [ GROUP ] <replaceable class="PARAMETER">rolename</replaceable> | PUBLIC } [, ...] [ CASCADE | RESTRICT ] REVOKE [ GRANT OPTION FOR ] { { SELECT | INSERT | UPDATE | REFERENCES } ( <replaceable class="PARAMETER">column</replaceable> [, ...] ) [,...] | ALL [ PRIVILEGES ] ( <replaceable class="PARAMETER">column</replaceable> [, ...] ) } ! ON [ TABLE | VIEW ] <replaceable class="PARAMETER">tablename</replaceable> [, ...] FROM { [ GROUP ] <replaceable class="PARAMETER">rolename</replaceable> | PUBLIC } [, ...] [ CASCADE | RESTRICT ] REVOKE [ GRANT OPTION FOR ] { { USAGE | SELECT | UPDATE } [,...] | ALL [ PRIVILEGES ] } ! ON { SEQUENCE <replaceable class="PARAMETER">sequencename</replaceable> [, ...] ! | ALL SEQUENCES IN <replaceable>schemaname</replaceable> [, ...] } FROM { [ GROUP ] <replaceable class="PARAMETER">rolename</replaceable> | PUBLIC } [, ...] [ CASCADE | RESTRICT ] *************** REVOKE [ GRANT OPTION FOR ] *** 62,68 **** REVOKE [ GRANT OPTION FOR ] { EXECUTE | ALL [ PRIVILEGES ] } ! ON FUNCTION <replaceable>funcname</replaceable> ( [ [ <replaceable class="parameter">argmode</replaceable> ] [ <replaceableclass="parameter">argname</replaceable> ] <replaceable class="parameter">argtype</replaceable> [, ...] ] ) [,...] FROM { [ GROUP ] <replaceable class="PARAMETER">rolename</replaceable> | PUBLIC } [, ...] [ CASCADE | RESTRICT ] --- 64,71 ---- REVOKE [ GRANT OPTION FOR ] { EXECUTE | ALL [ PRIVILEGES ] } ! ON { FUNCTION <replaceable>funcname</replaceable> ( [ [ <replaceable class="parameter">argmode</replaceable> ] [ <replaceableclass="parameter">argname</replaceable> ] <replaceable class="parameter">argtype</replaceable> [, ...] ] ) [,...] ! | ALL FUNCTIONS IN <replaceable>schemaname</replaceable> [, ...] } FROM { [ GROUP ] <replaceable class="PARAMETER">rolename</replaceable> | PUBLIC } [, ...] [ CASCADE | RESTRICT ] diff --git a/src/backend/catalog/aclchk.c b/src/backend/catalog/aclchk.c index ec4aaf0..0bf4eb1 100644 *** a/src/backend/catalog/aclchk.c --- b/src/backend/catalog/aclchk.c *************** static void ExecGrant_Namespace(Internal *** 61,66 **** --- 61,68 ---- static void ExecGrant_Tablespace(InternalGrant *grantStmt); static List *objectNamesToOids(GrantObjectType objtype, List *objnames); + static List *getNamespacesObjectsOids(GrantObjectType objtype, List *nspnames); + static List *getRelationsInNamespace(Oid namespaceId, char relkind); static void expand_col_privileges(List *colnames, Oid table_oid, AclMode this_privileges, AclMode *col_privileges, *************** ExecuteGrantStmt(GrantStmt *stmt) *** 286,292 **** */ istmt.is_grant = stmt->is_grant; istmt.objtype = stmt->objtype; ! istmt.objects = objectNamesToOids(stmt->objtype, stmt->objects); /* all_privs to be filled below */ /* privileges to be filled below */ istmt.col_privs = NIL; /* may get filled below */ --- 288,297 ---- */ istmt.is_grant = stmt->is_grant; istmt.objtype = stmt->objtype; ! if (stmt->is_schema) ! istmt.objects = getNamespacesObjectsOids(stmt->objtype, stmt->objects); ! else ! istmt.objects = objectNamesToOids(stmt->objtype, stmt->objects); /* all_privs to be filled below */ /* privileges to be filled below */ istmt.col_privs = NIL; /* may get filled below */ *************** ExecuteGrantStmt(GrantStmt *stmt) *** 325,330 **** --- 330,336 ---- * the object type. */ case ACL_OBJECT_RELATION: + case ACL_OBJECT_VIEW: all_privileges = ACL_ALL_RIGHTS_RELATION | ACL_ALL_RIGHTS_SEQUENCE; errormsg = gettext_noop("invalid privilege type %s for relation"); break; *************** ExecuteGrantStmt(GrantStmt *stmt) *** 394,400 **** */ if (privnode->cols) { ! if (stmt->objtype != ACL_OBJECT_RELATION) ereport(ERROR, (errcode(ERRCODE_INVALID_GRANT_OPERATION), errmsg("column privileges are only valid for relations"))); --- 400,406 ---- */ if (privnode->cols) { ! if (stmt->objtype != ACL_OBJECT_RELATION && stmt->objtype != ACL_OBJECT_VIEW) ereport(ERROR, (errcode(ERRCODE_INVALID_GRANT_OPERATION), errmsg("column privileges are only valid for relations"))); *************** ExecGrantStmt_oids(InternalGrant *istmt) *** 431,436 **** --- 437,443 ---- switch (istmt->objtype) { case ACL_OBJECT_RELATION: + case ACL_OBJECT_VIEW: case ACL_OBJECT_SEQUENCE: ExecGrant_Relation(istmt); break; *************** objectNamesToOids(GrantObjectType objtyp *** 477,482 **** --- 484,490 ---- switch (objtype) { case ACL_OBJECT_RELATION: + case ACL_OBJECT_VIEW: case ACL_OBJECT_SEQUENCE: foreach(cell, objnames) { *************** objectNamesToOids(GrantObjectType objtyp *** 609,614 **** --- 617,756 ---- return objects; } + + /* + * getNamespacesObjectsOids + * + * Get all objects of a given type from specified schema list into an Oid list. + */ + static List * + getNamespacesObjectsOids(GrantObjectType objtype, List *nspnames) + { + List *objects = NIL; + ListCell *cell; + char *nspname; + Oid namespaceId; + + switch (objtype) + { + case ACL_OBJECT_RELATION: + foreach(cell, nspnames) + { + List *relations = NIL; + + nspname = strVal(lfirst(cell)); + namespaceId = LookupExplicitNamespace(nspname); + + relations = getRelationsInNamespace(namespaceId, RELKIND_RELATION); + + objects = list_concat(objects, relations); + } + break; + case ACL_OBJECT_VIEW: + foreach(cell, nspnames) + { + List *relations = NIL; + + nspname = strVal(lfirst(cell)); + namespaceId = LookupExplicitNamespace(nspname); + + relations = getRelationsInNamespace(namespaceId, RELKIND_VIEW); + + objects = list_concat(objects, relations); + } + break; + case ACL_OBJECT_SEQUENCE: + foreach(cell, nspnames) + { + List *relations = NIL; + + nspname = strVal(lfirst(cell)); + namespaceId = LookupExplicitNamespace(nspname); + + relations = getRelationsInNamespace(namespaceId, RELKIND_SEQUENCE); + + objects = list_concat(objects, relations); + } + break; + case ACL_OBJECT_FUNCTION: + foreach(cell, nspnames) + { + ScanKeyData key[1]; + HeapScanDesc scan; + HeapTuple tuple; + Relation rel; + + nspname = strVal(lfirst(cell)); + namespaceId = LookupExplicitNamespace(nspname); + + ScanKeyInit(&key[0], + Anum_pg_proc_pronamespace, + BTEqualStrategyNumber, F_OIDEQ, + ObjectIdGetDatum(namespaceId)); + + rel = heap_open(ProcedureRelationId, AccessShareLock); + + scan = heap_beginscan(rel, SnapshotNow, 1, key); + + while ((tuple = heap_getnext(scan, ForwardScanDirection)) != NULL) + { + objects = lappend_oid(objects, HeapTupleGetOid(tuple)); + } + + heap_endscan(scan); + + heap_close(rel, AccessShareLock); + } + break; + default: + elog(ERROR, "unrecognized GrantStmt.objtype: %d", + (int) objtype); + } + + return objects; + } + + /* + * getRelationsInNamespace + * + * Return list of relations in given namespace filtered by relation kind + */ + static List * + getRelationsInNamespace(Oid namespaceId, char relkind) + { + List *relations = NIL; + ScanKeyData key[2]; + HeapScanDesc scan; + HeapTuple tuple; + Relation rel; + + ScanKeyInit(&key[0], + Anum_pg_class_relnamespace, + BTEqualStrategyNumber, F_OIDEQ, + ObjectIdGetDatum(namespaceId)); + + ScanKeyInit(&key[1], + Anum_pg_class_relkind, + BTEqualStrategyNumber, F_CHAREQ, + CharGetDatum(relkind)); + + rel = heap_open(RelationRelationId, AccessShareLock); + + scan = heap_beginscan(rel, SnapshotNow, 2, key); + + while ((tuple = heap_getnext(scan, ForwardScanDirection)) != NULL) + { + relations = lappend_oid(relations, HeapTupleGetOid(tuple)); + } + + heap_endscan(scan); + + heap_close(rel, AccessShareLock); + + return relations; + } + + /* * expand_col_privileges * *************** ExecGrant_Relation(InternalGrant *istmt) *** 912,918 **** * permissions. The OR of table and sequence permissions were already * checked. */ ! if (istmt->objtype == ACL_OBJECT_RELATION) { if (pg_class_tuple->relkind == RELKIND_SEQUENCE) { --- 1054,1060 ---- * permissions. The OR of table and sequence permissions were already * checked. */ ! if (istmt->objtype == ACL_OBJECT_RELATION || istmt->objtype == ACL_OBJECT_VIEW) { if (pg_class_tuple->relkind == RELKIND_SEQUENCE) { *************** ExecGrant_Relation(InternalGrant *istmt) *** 986,996 **** aclDatum = SysCacheGetAttr(RELOID, tuple, Anum_pg_class_relacl, &isNull); if (isNull) ! old_acl = acldefault(pg_class_tuple->relkind == RELKIND_SEQUENCE ? ! ACL_OBJECT_SEQUENCE : ACL_OBJECT_RELATION, ! ownerId); else old_acl = DatumGetAclPCopy(aclDatum); /* Need an extra copy of original rel ACL for column handling */ old_rel_acl = aclcopy(old_acl); --- 1128,1150 ---- aclDatum = SysCacheGetAttr(RELOID, tuple, Anum_pg_class_relacl, &isNull); if (isNull) ! { ! switch (pg_class_tuple->relkind) ! { ! case RELKIND_SEQUENCE: ! old_acl = acldefault(ACL_OBJECT_SEQUENCE, ownerId); ! break; ! case RELKIND_VIEW: ! old_acl = acldefault(ACL_OBJECT_VIEW, ownerId); ! break; ! default: ! old_acl = acldefault(ACL_OBJECT_RELATION, ownerId); ! } ! } else + { old_acl = DatumGetAclPCopy(aclDatum); + } /* Need an extra copy of original rel ACL for column handling */ old_rel_acl = aclcopy(old_acl); *************** pg_class_aclmask(Oid table_oid, Oid role *** 2434,2442 **** if (isNull) { /* No ACL, so build default ACL */ ! acl = acldefault(classForm->relkind == RELKIND_SEQUENCE ? ! ACL_OBJECT_SEQUENCE : ACL_OBJECT_RELATION, ! ownerId); aclDatum = (Datum) 0; } else --- 2588,2604 ---- if (isNull) { /* No ACL, so build default ACL */ ! switch (classForm->relkind) ! { ! case RELKIND_SEQUENCE: ! acl = acldefault(ACL_OBJECT_SEQUENCE, ownerId); ! break; ! case RELKIND_VIEW: ! acl = acldefault(ACL_OBJECT_VIEW, ownerId); ! break; ! default: ! acl = acldefault(ACL_OBJECT_RELATION, ownerId); ! } aclDatum = (Datum) 0; } else diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y index ac17b93..8d543b4 100644 *** a/src/backend/parser/gram.y --- b/src/backend/parser/gram.y *************** static bool QueryIsRule = FALSE; *** 99,104 **** --- 99,105 ---- typedef struct PrivTarget { GrantObjectType objtype; + bool is_schema; List *objs; } PrivTarget; *************** static TypeName *TableFuncTypeName(List *** 449,455 **** EXCLUDING EXCLUSIVE EXECUTE EXISTS EXPLAIN EXTERNAL EXTRACT FALSE_P FAMILY FETCH FIRST_P FLOAT_P FOLLOWING FOR FORCE FOREIGN FORWARD ! FREEZE FROM FULL FUNCTION GLOBAL GRANT GRANTED GREATEST GROUP_P --- 450,456 ---- EXCLUDING EXCLUSIVE EXECUTE EXISTS EXPLAIN EXTERNAL EXTRACT FALSE_P FAMILY FETCH FIRST_P FLOAT_P FOLLOWING FOR FORCE FOREIGN FORWARD ! FREEZE FROM FULL FUNCTION FUNCTIONS GLOBAL GRANT GRANTED GREATEST GROUP_P *************** static TypeName *TableFuncTypeName(List *** 487,499 **** RELATIVE_P RELEASE RENAME REPEATABLE REPLACE REPLICA RESET RESTART RESTRICT RETURNING RETURNS REVOKE RIGHT ROLE ROLLBACK ROW ROWS RULE ! SAVEPOINT SCHEMA SCROLL SEARCH SECOND_P SECURITY SELECT SEQUENCE SERIALIZABLE SERVER SESSION SESSION_USER SET SETOF SHARE SHOW SIMILAR SIMPLE SMALLINT SOME STABLE STANDALONE_P START STATEMENT STATISTICS STDIN STDOUT STORAGE STRICT_P STRIP_P SUBSTRING SUPERUSER_P SYMMETRIC SYSID SYSTEM_P ! TABLE TABLESPACE TEMP TEMPLATE TEMPORARY TEXT_P THEN TIME TIMESTAMP TO TRAILING TRANSACTION TREAT TRIGGER TRIM TRUE_P TRUNCATE TRUSTED TYPE_P --- 488,500 ---- RELATIVE_P RELEASE RENAME REPEATABLE REPLACE REPLICA RESET RESTART RESTRICT RETURNING RETURNS REVOKE RIGHT ROLE ROLLBACK ROW ROWS RULE ! SAVEPOINT SCHEMA SCROLL SEARCH SECOND_P SECURITY SELECT SEQUENCE SEQUENCES SERIALIZABLE SERVER SESSION SESSION_USER SET SETOF SHARE SHOW SIMILAR SIMPLE SMALLINT SOME STABLE STANDALONE_P START STATEMENT STATISTICS STDIN STDOUT STORAGE STRICT_P STRIP_P SUBSTRING SUPERUSER_P SYMMETRIC SYSID SYSTEM_P ! TABLE TABLES TABLESPACE TEMP TEMPLATE TEMPORARY TEXT_P THEN TIME TIMESTAMP TO TRAILING TRANSACTION TREAT TRIGGER TRIM TRUE_P TRUNCATE TRUSTED TYPE_P *************** static TypeName *TableFuncTypeName(List *** 501,507 **** UPDATE USER USING VACUUM VALID VALIDATOR VALUE_P VALUES VARCHAR VARIADIC VARYING ! VERBOSE VERSION_P VIEW VOLATILE WHEN WHERE WHITESPACE_P WINDOW WITH WITHOUT WORK WRAPPER WRITE --- 502,508 ---- UPDATE USER USING VACUUM VALID VALIDATOR VALUE_P VALUES VARCHAR VARIADIC VARYING ! VERBOSE VERSION_P VIEW VIEWS VOLATILE WHEN WHERE WHITESPACE_P WINDOW WITH WITHOUT WORK WRAPPER WRITE *************** GrantStmt: GRANT privileges ON privilege *** 4216,4221 **** --- 4217,4223 ---- n->is_grant = true; n->privileges = $2; n->objtype = ($4)->objtype; + n->is_schema = ($4)->is_schema; n->objects = ($4)->objs; n->grantees = $6; n->grant_option = $7; *************** RevokeStmt: *** 4232,4237 **** --- 4234,4240 ---- n->grant_option = false; n->privileges = $2; n->objtype = ($4)->objtype; + n->is_schema = ($4)->is_schema; n->objects = ($4)->objs; n->grantees = $6; n->behavior = $7; *************** RevokeStmt: *** 4245,4250 **** --- 4248,4254 ---- n->grant_option = true; n->privileges = $5; n->objtype = ($7)->objtype; + n->is_schema = ($7)->is_schema; n->objects = ($7)->objs; n->grantees = $9; n->behavior = $10; *************** privilege_target: *** 4327,4332 **** --- 4331,4337 ---- { PrivTarget *n = (PrivTarget *) palloc(sizeof(PrivTarget)); n->objtype = ACL_OBJECT_RELATION; + n->is_schema = FALSE; n->objs = $1; $$ = n; } *************** privilege_target: *** 4334,4339 **** --- 4339,4353 ---- { PrivTarget *n = (PrivTarget *) palloc(sizeof(PrivTarget)); n->objtype = ACL_OBJECT_RELATION; + n->is_schema = FALSE; + n->objs = $2; + $$ = n; + } + | VIEW qualified_name_list + { + PrivTarget *n = (PrivTarget *) palloc(sizeof(PrivTarget)); + n->objtype = ACL_OBJECT_VIEW; + n->is_schema = FALSE; n->objs = $2; $$ = n; } *************** privilege_target: *** 4341,4346 **** --- 4355,4361 ---- { PrivTarget *n = (PrivTarget *) palloc(sizeof(PrivTarget)); n->objtype = ACL_OBJECT_SEQUENCE; + n->is_schema = FALSE; n->objs = $2; $$ = n; } *************** privilege_target: *** 4348,4353 **** --- 4363,4369 ---- { PrivTarget *n = (PrivTarget *) palloc(sizeof(PrivTarget)); n->objtype = ACL_OBJECT_FDW; + n->is_schema = FALSE; n->objs = $4; $$ = n; } *************** privilege_target: *** 4355,4360 **** --- 4371,4377 ---- { PrivTarget *n = (PrivTarget *) palloc(sizeof(PrivTarget)); n->objtype = ACL_OBJECT_FOREIGN_SERVER; + n->is_schema = FALSE; n->objs = $3; $$ = n; } *************** privilege_target: *** 4362,4367 **** --- 4379,4385 ---- { PrivTarget *n = (PrivTarget *) palloc(sizeof(PrivTarget)); n->objtype = ACL_OBJECT_FUNCTION; + n->is_schema = FALSE; n->objs = $2; $$ = n; } *************** privilege_target: *** 4369,4374 **** --- 4387,4393 ---- { PrivTarget *n = (PrivTarget *) palloc(sizeof(PrivTarget)); n->objtype = ACL_OBJECT_DATABASE; + n->is_schema = FALSE; n->objs = $2; $$ = n; } *************** privilege_target: *** 4376,4381 **** --- 4395,4401 ---- { PrivTarget *n = (PrivTarget *) palloc(sizeof(PrivTarget)); n->objtype = ACL_OBJECT_LANGUAGE; + n->is_schema = FALSE; n->objs = $2; $$ = n; } *************** privilege_target: *** 4383,4388 **** --- 4403,4409 ---- { PrivTarget *n = (PrivTarget *) palloc(sizeof(PrivTarget)); n->objtype = ACL_OBJECT_NAMESPACE; + n->is_schema = FALSE; n->objs = $2; $$ = n; } *************** privilege_target: *** 4390,4398 **** --- 4411,4452 ---- { PrivTarget *n = (PrivTarget *) palloc(sizeof(PrivTarget)); n->objtype = ACL_OBJECT_TABLESPACE; + n->is_schema = FALSE; n->objs = $2; $$ = n; } + | ALL TABLES IN_P name_list + { + PrivTarget *n = (PrivTarget *) palloc(sizeof(PrivTarget)); + n->objtype = ACL_OBJECT_RELATION; + n->is_schema = TRUE; + n->objs = $4; + $$ = n; + } + | ALL VIEWS IN_P name_list + { + PrivTarget *n = (PrivTarget *) palloc(sizeof(PrivTarget)); + n->objtype = ACL_OBJECT_VIEW; + n->is_schema = TRUE; + n->objs = $4; + $$ = n; + } + | ALL SEQUENCES IN_P name_list + { + PrivTarget *n = (PrivTarget *) palloc(sizeof(PrivTarget)); + n->objtype = ACL_OBJECT_SEQUENCE; + n->is_schema = TRUE; + n->objs = $4; + $$ = n; + } + | ALL FUNCTIONS IN_P name_list + { + PrivTarget *n = (PrivTarget *) palloc(sizeof(PrivTarget)); + n->objtype = ACL_OBJECT_FUNCTION; + n->is_schema = TRUE; + n->objs = $4; + $$ = n; + } ; *************** unreserved_keyword: *** 10201,10206 **** --- 10255,10261 ---- | FORCE | FORWARD | FUNCTION + | FUNCTIONS | GLOBAL | GRANTED | HANDLER *************** unreserved_keyword: *** 10310,10315 **** --- 10365,10371 ---- | SECOND_P | SECURITY | SEQUENCE + | SEQUENCES | SERIALIZABLE | SERVER | SESSION *************** unreserved_keyword: *** 10330,10335 **** --- 10386,10392 ---- | SUPERUSER_P | SYSID | SYSTEM_P + | TABLES | TABLESPACE | TEMP | TEMPLATE *************** unreserved_keyword: *** 10354,10359 **** --- 10411,10417 ---- | VARYING | VERSION_P | VIEW + | VIEWS | VOLATILE | WHITESPACE_P | WITHOUT diff --git a/src/backend/utils/adt/acl.c b/src/backend/utils/adt/acl.c index 334823b..ddd92e7 100644 *** a/src/backend/utils/adt/acl.c --- b/src/backend/utils/adt/acl.c *************** acldefault(GrantObjectType objtype, Oid *** 609,614 **** --- 609,615 ---- owner_default = ACL_NO_RIGHTS; break; case ACL_OBJECT_RELATION: + case ACL_OBJECT_VIEW: world_default = ACL_NO_RIGHTS; owner_default = ACL_ALL_RIGHTS_RELATION; break; diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h index a108b80..fa040df 100644 *** a/src/include/nodes/parsenodes.h --- b/src/include/nodes/parsenodes.h *************** typedef struct AlterDomainStmt *** 1180,1186 **** typedef enum GrantObjectType { ACL_OBJECT_COLUMN, /* column */ ! ACL_OBJECT_RELATION, /* table, view */ ACL_OBJECT_SEQUENCE, /* sequence */ ACL_OBJECT_DATABASE, /* database */ ACL_OBJECT_FDW, /* foreign-data wrapper */ --- 1180,1186 ---- typedef enum GrantObjectType { ACL_OBJECT_COLUMN, /* column */ ! ACL_OBJECT_RELATION, /* table */ ACL_OBJECT_SEQUENCE, /* sequence */ ACL_OBJECT_DATABASE, /* database */ ACL_OBJECT_FDW, /* foreign-data wrapper */ *************** typedef enum GrantObjectType *** 1188,1194 **** ACL_OBJECT_FUNCTION, /* function */ ACL_OBJECT_LANGUAGE, /* procedural language */ ACL_OBJECT_NAMESPACE, /* namespace */ ! ACL_OBJECT_TABLESPACE /* tablespace */ } GrantObjectType; typedef struct GrantStmt --- 1188,1195 ---- ACL_OBJECT_FUNCTION, /* function */ ACL_OBJECT_LANGUAGE, /* procedural language */ ACL_OBJECT_NAMESPACE, /* namespace */ ! ACL_OBJECT_TABLESPACE, /* tablespace */ ! ACL_OBJECT_VIEW, /* view */ } GrantObjectType; typedef struct GrantStmt *************** typedef struct GrantStmt *** 1196,1201 **** --- 1197,1204 ---- NodeTag type; bool is_grant; /* true = GRANT, false = REVOKE */ GrantObjectType objtype; /* kind of object being operated on */ + bool is_schema; /* if true we want all objects + * of objtype in schema */ List *objects; /* list of RangeVar nodes, FuncWithArgs nodes, * or plain names (as Value strings) */ List *privileges; /* list of AccessPriv nodes */ diff --git a/src/include/parser/kwlist.h b/src/include/parser/kwlist.h index 67e9cb4..a6ae56c 100644 *** a/src/include/parser/kwlist.h --- b/src/include/parser/kwlist.h *************** PG_KEYWORD("freeze", FREEZE, TYPE_FUNC_N *** 163,168 **** --- 163,169 ---- PG_KEYWORD("from", FROM, RESERVED_KEYWORD) PG_KEYWORD("full", FULL, TYPE_FUNC_NAME_KEYWORD) PG_KEYWORD("function", FUNCTION, UNRESERVED_KEYWORD) + PG_KEYWORD("functions", FUNCTIONS, UNRESERVED_KEYWORD) PG_KEYWORD("global", GLOBAL, UNRESERVED_KEYWORD) PG_KEYWORD("grant", GRANT, RESERVED_KEYWORD) PG_KEYWORD("granted", GRANTED, UNRESERVED_KEYWORD) *************** PG_KEYWORD("second", SECOND_P, UNRESERVE *** 328,333 **** --- 329,335 ---- PG_KEYWORD("security", SECURITY, UNRESERVED_KEYWORD) PG_KEYWORD("select", SELECT, RESERVED_KEYWORD) PG_KEYWORD("sequence", SEQUENCE, UNRESERVED_KEYWORD) + PG_KEYWORD("sequences", SEQUENCES, UNRESERVED_KEYWORD) PG_KEYWORD("serializable", SERIALIZABLE, UNRESERVED_KEYWORD) PG_KEYWORD("server", SERVER, UNRESERVED_KEYWORD) PG_KEYWORD("session", SESSION, UNRESERVED_KEYWORD) *************** PG_KEYWORD("symmetric", SYMMETRIC, RESER *** 356,361 **** --- 358,364 ---- PG_KEYWORD("sysid", SYSID, UNRESERVED_KEYWORD) PG_KEYWORD("system", SYSTEM_P, UNRESERVED_KEYWORD) PG_KEYWORD("table", TABLE, RESERVED_KEYWORD) + PG_KEYWORD("tables", TABLES, UNRESERVED_KEYWORD) PG_KEYWORD("tablespace", TABLESPACE, UNRESERVED_KEYWORD) PG_KEYWORD("temp", TEMP, UNRESERVED_KEYWORD) PG_KEYWORD("template", TEMPLATE, UNRESERVED_KEYWORD) *************** PG_KEYWORD("varying", VARYING, UNRESERVE *** 396,401 **** --- 399,405 ---- PG_KEYWORD("verbose", VERBOSE, TYPE_FUNC_NAME_KEYWORD) PG_KEYWORD("version", VERSION_P, UNRESERVED_KEYWORD) PG_KEYWORD("view", VIEW, UNRESERVED_KEYWORD) + PG_KEYWORD("views", VIEWS, UNRESERVED_KEYWORD) PG_KEYWORD("volatile", VOLATILE, UNRESERVED_KEYWORD) PG_KEYWORD("when", WHEN, RESERVED_KEYWORD) PG_KEYWORD("where", WHERE, RESERVED_KEYWORD) diff --git a/src/test/regress/expected/privileges.out b/src/test/regress/expected/privileges.out index a17ff59..043c0f3 100644 *** a/src/test/regress/expected/privileges.out --- b/src/test/regress/expected/privileges.out *************** SELECT has_table_privilege('regressuser1 *** 815,820 **** --- 815,849 ---- t (1 row) + -- Grant on all objects of given type in a schema + RESET SESSION AUTHORIZATION; + REVOKE ALL ON ALL TABLES IN public FROM regressuser1; + SELECT has_table_privilege('regressuser1', 'atest1', 'SELECT'); -- false + has_table_privilege + --------------------- + f + (1 row) + + REVOKE ALL ON ALL FUNCTIONS IN public FROM regressuser1; + SET SESSION AUTHORIZATION regressuser1; + SELECT testfunc2(5); -- fail + ERROR: permission denied for function testfunc2 + RESET SESSION AUTHORIZATION; + GRANT ALL ON ALL TABLES IN public TO regressuser1; + SELECT has_table_privilege('regressuser1', 'atest2', 'SELECT'); -- true + has_table_privilege + --------------------- + t + (1 row) + + GRANT ALL ON ALL FUNCTIONS IN public TO regressuser1; + SET SESSION AUTHORIZATION regressuser1; + SELECT testfunc2(5); -- ok + testfunc2 + ----------- + 15 + (1 row) + -- clean up \c DROP FUNCTION testfunc2(int); *************** DROP TABLE atestp2; *** 839,844 **** --- 868,875 ---- DROP GROUP regressgroup1; DROP GROUP regressgroup2; REVOKE USAGE ON LANGUAGE sql FROM regressuser1; + REVOKE ALL ON ALL TABLES IN public FROM regressuser1; + REVOKE ALL ON ALL FUNCTIONS IN public FROM regressuser1; DROP USER regressuser1; DROP USER regressuser2; DROP USER regressuser3; diff --git a/src/test/regress/sql/privileges.sql b/src/test/regress/sql/privileges.sql index 5aa1012..e574c4d 100644 *** a/src/test/regress/sql/privileges.sql --- b/src/test/regress/sql/privileges.sql *************** SELECT has_table_privilege('regressuser3 *** 469,474 **** --- 469,500 ---- SELECT has_table_privilege('regressuser1', 'atest4', 'SELECT WITH GRANT OPTION'); -- true + -- Grant on all objects of given type in a schema + + RESET SESSION AUTHORIZATION; + + REVOKE ALL ON ALL TABLES IN public FROM regressuser1; + + SELECT has_table_privilege('regressuser1', 'atest1', 'SELECT'); -- false + + REVOKE ALL ON ALL FUNCTIONS IN public FROM regressuser1; + + SET SESSION AUTHORIZATION regressuser1; + + SELECT testfunc2(5); -- fail + + RESET SESSION AUTHORIZATION; + + GRANT ALL ON ALL TABLES IN public TO regressuser1; + + SELECT has_table_privilege('regressuser1', 'atest2', 'SELECT'); -- true + + GRANT ALL ON ALL FUNCTIONS IN public TO regressuser1; + + SET SESSION AUTHORIZATION regressuser1; + + SELECT testfunc2(5); -- ok + -- clean up \c *************** DROP GROUP regressgroup1; *** 497,502 **** --- 523,530 ---- DROP GROUP regressgroup2; REVOKE USAGE ON LANGUAGE sql FROM regressuser1; + REVOKE ALL ON ALL TABLES IN public FROM regressuser1; + REVOKE ALL ON ALL FUNCTIONS IN public FROM regressuser1; DROP USER regressuser1; DROP USER regressuser2; DROP USER regressuser3;
On Fri, 2009-07-03 at 12:44 +0200, Petr Jelinek wrote: > Petr Jelinek wrote: > > So, here is the first version of the patch. > Attached is v2 with slightly improved code, nothing has changed > feature-wise. I would like to see GRANT ... ON ALL OBJECTS ... because I know that I will forget to do TABLES, VIEWS and SEQUENCES every time I want to do this. If we are aggregating all objects of a type, why not aggregate all objects, so we just issue one command? (I'm sure we can do something intelligent with privileges that don't apply to all object types rather than just fail. e.g. UPDATE privilege should be same as USAGE on a sequence.) -- Simon Riggs www.2ndQuadrant.comPostgreSQL Training, Services and Support
Simon Riggs <simon@2ndQuadrant.com> writes: > I would like to see > GRANT ... ON ALL OBJECTS ... This seems inherently broken, since different types of objects will have different grantable privileges. > (I'm sure we can do something intelligent with privileges that don't > apply to all object types rather than just fail. e.g. UPDATE privilege > should be same as USAGE on a sequence.) Anything you do in that line will be an ugly kluge, and will tend to encourage insecure over-granting of privileges (ie GRANT ALL ON ALL OBJECTS ... what's the point of using permissions at all then?) regards, tom lane
On Tue, Jul 7, 2009 at 4:16 PM, Tom Lane<tgl@sss.pgh.pa.us> wrote: > >> (I'm sure we can do something intelligent with privileges that don't >> apply to all object types rather than just fail. e.g. UPDATE privilege >> should be same as USAGE on a sequence.) > > Anything you do in that line will be an ugly kluge, and will tend to > encourage insecure over-granting of privileges (ie GRANT ALL ON ALL > OBJECTS ... what's the point of using permissions at all then?) That seems a bit pessimistic. While I disagree with Simon's rule I think you can get plenty of mileage out of a more conservative rule of just granting the privilege to all objects for which that privilege is defined. Especially when you consider that we allow listing multiple privileges in a single command. -- greg http://mit.edu/~gsstark/resume.pdf
On Tue, 2009-07-07 at 11:16 -0400, Tom Lane wrote: > Simon Riggs <simon@2ndQuadrant.com> writes: > > I would like to see > > GRANT ... ON ALL OBJECTS ... > > This seems inherently broken, since different types of objects > will have different grantable privileges. > > > (I'm sure we can do something intelligent with privileges that don't > > apply to all object types rather than just fail. e.g. UPDATE privilege > > should be same as USAGE on a sequence.) > > Anything you do in that line will be an ugly kluge, and will tend to > encourage insecure over-granting of privileges (ie GRANT ALL ON ALL > OBJECTS ... what's the point of using permissions at all then?) My perspective would be that privilege systems that are too complex fall into disuse, leading to less security, not more. On any database that has moderate security or better permissions errors are one of the three errors on production databases. Simplifying the commands, by aggregating them or another way, is likely to yield benefits in usability for a wide range of users. Unix allows chmod to run against multiple object types. How annoying would it be if you had to issue chmodfile, chmodlink, chmoddir separately for each class of object. (Links don't barf if you try to set their file mode, for example). We follow the Unix file system in many other ways, why not this one? -- Simon Riggs www.2ndQuadrant.comPostgreSQL Training, Services and Support
Hi, > > Attached is v2 with slightly improved code, nothing has changed > feature-wise. > Here are some comments on this patch from my side: grant.sgml * Maybe we should use <replaceable class="parameter">schemaname</replaceable> in the sgml references instead of just <replaceable>schemaname</replaceable> + There is also the posibility of granting permissions to all objects of + given type inside one or multiple schemas. This functionality is supported + for tables, views, sequences and functions and can done by using + ALL TABLES IN schemanema syntax in place of object name. + </para> + + <para> typo "posibility" It should be ALL [TABLES|VIEWS|SEQUENCES|FUNCTIONS} IN schemaname (note the other typo here) syntax to be precise IMHO. aclchk.c + elog(ERROR, "unrecognized GrantStmt.objtype: %d", + (int) objtype); Kinda funny to mention the C structure name in the error. But I see that the other functions in the file do the same, so should be ok. I doubt if the syntax allows any other object type to reach upto this function anyways :) parsenodes.h GrantObjectType objtype; /* kind of object being operated on */ + bool is_schema; /* if true we want all objects + * of objtype in schema */ You forgot to make changes in _copyGrantStmt and _equalGrantStmt to account for this new field. Rest of the changes look straightforward and ok to me. make installcheck passes cleanly too. I also do not see any new warnings due to this patch. As an aside, I was just wondering the behaviour for RELKIND_INDEX? Regards, Nikhils -- http://www.enterprisedb.com
Nikhil Sontakke wrote: > grant.sgml > * Maybe we should use > <replaceable class="parameter">schemaname</replaceable> in the sgml > references instead of just <replaceable>schemaname</replaceable> > > + There is also the posibility of granting permissions to all objects of > + given type inside one or multiple schemas. This functionality is supported > + for tables, views, sequences and functions and can done by using > + ALL TABLES IN schemanema syntax in place of object name. > + </para> > + > + <para> > > typo "posibility" > It should be ALL [TABLES|VIEWS|SEQUENCES|FUNCTIONS} IN schemaname > (note the other typo here) syntax to be precise IMHO. > Right, fixed. > aclchk.c > + elog(ERROR, "unrecognized GrantStmt.objtype: %d", > + (int) objtype); > > Kinda funny to mention the C structure name in the error. But I see > that the other functions in the file do the same, so should be ok. I > doubt if the syntax allows any other object type to reach upto this > function anyways :) > It's copy paste :) But it seemed a bit strange to me too as this kind of thing is not recommended in developer "guide". On the other hand ordinary user should not ever see this unless something is horribly wrong with bison. > parsenodes.h > GrantObjectType objtype; /* kind of object being operated on */ > + bool is_schema; /* if true we want all objects > + * of objtype in schema */ > > You forgot to make changes in _copyGrantStmt and _equalGrantStmt to > account for this new field. > Fixed. > As an aside, I was just wondering the behaviour for RELKIND_INDEX? > Indexes don't have permissions afaik so nothing. I attached modified patch per your comments and also updated to current HEAD. Thanks for your review. -- Regards Petr Jelinek (PJMODOS) diff --git a/doc/src/sgml/ref/grant.sgml b/doc/src/sgml/ref/grant.sgml index bf963b8..51aad15 100644 *** a/doc/src/sgml/ref/grant.sgml --- b/doc/src/sgml/ref/grant.sgml *************** PostgreSQL documentation *** 23,39 **** <synopsis> GRANT { { SELECT | INSERT | UPDATE | DELETE | TRUNCATE | REFERENCES | TRIGGER } [,...] | ALL [ PRIVILEGES ] } ! ON [ TABLE ] <replaceable class="PARAMETER">tablename</replaceable> [, ...] TO { [ GROUP ] <replaceable class="PARAMETER">rolename</replaceable> | PUBLIC } [, ...] [ WITH GRANT OPTION ] GRANT { { SELECT | INSERT | UPDATE | REFERENCES } ( <replaceable class="PARAMETER">column</replaceable> [, ...] ) [,...] | ALL [ PRIVILEGES ] ( <replaceable class="PARAMETER">column</replaceable> [, ...] ) } ! ON [ TABLE ] <replaceable class="PARAMETER">tablename</replaceable> [, ...] TO { [ GROUP ] <replaceable class="PARAMETER">rolename</replaceable> | PUBLIC } [, ...] [ WITH GRANT OPTION ] GRANT { { USAGE | SELECT | UPDATE } [,...] | ALL [ PRIVILEGES ] } ! ON SEQUENCE <replaceable class="PARAMETER">sequencename</replaceable> [, ...] TO { [ GROUP ] <replaceable class="PARAMETER">rolename</replaceable> | PUBLIC } [, ...] [ WITH GRANT OPTION ] GRANT { { CREATE | CONNECT | TEMPORARY | TEMP } [,...] | ALL [ PRIVILEGES ] } --- 23,41 ---- <synopsis> GRANT { { SELECT | INSERT | UPDATE | DELETE | TRUNCATE | REFERENCES | TRIGGER } [,...] | ALL [ PRIVILEGES ] } ! ON { { [ TABLE | VIEW ] <replaceable class="PARAMETER">tablename</replaceable> [, ...] } ! | ALL [ TABLES | VIEWS ] IN <replaceable class="PARAMETER">schemaname</replaceable> [, ...] } TO { [ GROUP ] <replaceable class="PARAMETER">rolename</replaceable> | PUBLIC } [, ...] [ WITH GRANT OPTION ] GRANT { { SELECT | INSERT | UPDATE | REFERENCES } ( <replaceable class="PARAMETER">column</replaceable> [, ...] ) [,...] | ALL [ PRIVILEGES ] ( <replaceable class="PARAMETER">column</replaceable> [, ...] ) } ! ON [ TABLE | VIEW ] <replaceable class="PARAMETER">tablename</replaceable> [, ...] TO { [ GROUP ] <replaceable class="PARAMETER">rolename</replaceable> | PUBLIC } [, ...] [ WITH GRANT OPTION ] GRANT { { USAGE | SELECT | UPDATE } [,...] | ALL [ PRIVILEGES ] } ! ON { SEQUENCE <replaceable class="PARAMETER">sequencename</replaceable> [, ...] ! | ALL SEQUENCES IN <replaceable class="PARAMETER">schemaname</replaceable> [, ...] } TO { [ GROUP ] <replaceable class="PARAMETER">rolename</replaceable> | PUBLIC } [, ...] [ WITH GRANT OPTION ] GRANT { { CREATE | CONNECT | TEMPORARY | TEMP } [,...] | ALL [ PRIVILEGES ] } *************** GRANT { USAGE | ALL [ PRIVILEGES ] } *** 49,55 **** TO { [ GROUP ] <replaceable class="PARAMETER">rolename</replaceable> | PUBLIC } [, ...] [ WITH GRANT OPTION ] GRANT { EXECUTE | ALL [ PRIVILEGES ] } ! ON FUNCTION <replaceable>funcname</replaceable> ( [ [ <replaceable class="parameter">argmode</replaceable> ] [ <replaceableclass="parameter">argname</replaceable> ] <replaceable class="parameter">argtype</replaceable> [, ...] ] ) [,...] TO { [ GROUP ] <replaceable class="PARAMETER">rolename</replaceable> | PUBLIC } [, ...] [ WITH GRANT OPTION ] GRANT { USAGE | ALL [ PRIVILEGES ] } --- 51,58 ---- TO { [ GROUP ] <replaceable class="PARAMETER">rolename</replaceable> | PUBLIC } [, ...] [ WITH GRANT OPTION ] GRANT { EXECUTE | ALL [ PRIVILEGES ] } ! ON { FUNCTION <replaceable>funcname</replaceable> ( [ [ <replaceable class="parameter">argmode</replaceable> ] [ <replaceableclass="parameter">argname</replaceable> ] <replaceable class="parameter">argtype</replaceable> [, ...] ] ) [,...] ! | ALL FUNCTIONS IN <replaceable class="PARAMETER">schemaname</replaceable> [, ...] } TO { [ GROUP ] <replaceable class="PARAMETER">rolename</replaceable> | PUBLIC } [, ...] [ WITH GRANT OPTION ] GRANT { USAGE | ALL [ PRIVILEGES ] } *************** GRANT <replaceable class="PARAMETER">rol *** 143,148 **** --- 146,159 ---- </para> <para> + There is also the possibility of granting permissions to all objects of + given type inside one or multiple schemas. This functionality is supported + for tables, views, sequences and functions and can done by using + ALL {TABLES|VIEWS|SEQUENCES|FUNCTIONS} IN schemanema syntax in place + of object name. + </para> + + <para> The possible privileges are: <variablelist> diff --git a/doc/src/sgml/ref/revoke.sgml b/doc/src/sgml/ref/revoke.sgml index 8d62580..ac0905f 100644 *** a/doc/src/sgml/ref/revoke.sgml --- b/doc/src/sgml/ref/revoke.sgml *************** PostgreSQL documentation *** 24,44 **** REVOKE [ GRANT OPTION FOR ] { { SELECT | INSERT | UPDATE | DELETE | TRUNCATE | REFERENCES | TRIGGER } [,...] | ALL [ PRIVILEGES ] } ! ON [ TABLE ] <replaceable class="PARAMETER">tablename</replaceable> [, ...] FROM { [ GROUP ] <replaceable class="PARAMETER">rolename</replaceable> | PUBLIC } [, ...] [ CASCADE | RESTRICT ] REVOKE [ GRANT OPTION FOR ] { { SELECT | INSERT | UPDATE | REFERENCES } ( <replaceable class="PARAMETER">column</replaceable> [, ...] ) [,...] | ALL [ PRIVILEGES ] ( <replaceable class="PARAMETER">column</replaceable> [, ...] ) } ! ON [ TABLE ] <replaceable class="PARAMETER">tablename</replaceable> [, ...] FROM { [ GROUP ] <replaceable class="PARAMETER">rolename</replaceable> | PUBLIC } [, ...] [ CASCADE | RESTRICT ] REVOKE [ GRANT OPTION FOR ] { { USAGE | SELECT | UPDATE } [,...] | ALL [ PRIVILEGES ] } ! ON SEQUENCE <replaceable class="PARAMETER">sequencename</replaceable> [, ...] FROM { [ GROUP ] <replaceable class="PARAMETER">rolename</replaceable> | PUBLIC } [, ...] [ CASCADE | RESTRICT ] --- 24,46 ---- REVOKE [ GRANT OPTION FOR ] { { SELECT | INSERT | UPDATE | DELETE | TRUNCATE | REFERENCES | TRIGGER } [,...] | ALL [ PRIVILEGES ] } ! ON { { [ TABLE | VIEW ] <replaceable class="PARAMETER">tablename</replaceable> [, ...] } ! | ALL [ TABLES | VIEWS ] IN <replaceable>schemaname</replaceable> [, ...] } FROM { [ GROUP ] <replaceable class="PARAMETER">rolename</replaceable> | PUBLIC } [, ...] [ CASCADE | RESTRICT ] REVOKE [ GRANT OPTION FOR ] { { SELECT | INSERT | UPDATE | REFERENCES } ( <replaceable class="PARAMETER">column</replaceable> [, ...] ) [,...] | ALL [ PRIVILEGES ] ( <replaceable class="PARAMETER">column</replaceable> [, ...] ) } ! ON [ TABLE | VIEW ] <replaceable class="PARAMETER">tablename</replaceable> [, ...] FROM { [ GROUP ] <replaceable class="PARAMETER">rolename</replaceable> | PUBLIC } [, ...] [ CASCADE | RESTRICT ] REVOKE [ GRANT OPTION FOR ] { { USAGE | SELECT | UPDATE } [,...] | ALL [ PRIVILEGES ] } ! ON { SEQUENCE <replaceable class="PARAMETER">sequencename</replaceable> [, ...] ! | ALL SEQUENCES IN <replaceable>schemaname</replaceable> [, ...] } FROM { [ GROUP ] <replaceable class="PARAMETER">rolename</replaceable> | PUBLIC } [, ...] [ CASCADE | RESTRICT ] *************** REVOKE [ GRANT OPTION FOR ] *** 62,68 **** REVOKE [ GRANT OPTION FOR ] { EXECUTE | ALL [ PRIVILEGES ] } ! ON FUNCTION <replaceable>funcname</replaceable> ( [ [ <replaceable class="parameter">argmode</replaceable> ] [ <replaceableclass="parameter">argname</replaceable> ] <replaceable class="parameter">argtype</replaceable> [, ...] ] ) [,...] FROM { [ GROUP ] <replaceable class="PARAMETER">rolename</replaceable> | PUBLIC } [, ...] [ CASCADE | RESTRICT ] --- 64,71 ---- REVOKE [ GRANT OPTION FOR ] { EXECUTE | ALL [ PRIVILEGES ] } ! ON { FUNCTION <replaceable>funcname</replaceable> ( [ [ <replaceable class="parameter">argmode</replaceable> ] [ <replaceableclass="parameter">argname</replaceable> ] <replaceable class="parameter">argtype</replaceable> [, ...] ] ) [,...] ! | ALL FUNCTIONS IN <replaceable>schemaname</replaceable> [, ...] } FROM { [ GROUP ] <replaceable class="PARAMETER">rolename</replaceable> | PUBLIC } [, ...] [ CASCADE | RESTRICT ] diff --git a/src/backend/catalog/aclchk.c b/src/backend/catalog/aclchk.c index ec4aaf0..0bf4eb1 100644 *** a/src/backend/catalog/aclchk.c --- b/src/backend/catalog/aclchk.c *************** static void ExecGrant_Namespace(Internal *** 61,66 **** --- 61,68 ---- static void ExecGrant_Tablespace(InternalGrant *grantStmt); static List *objectNamesToOids(GrantObjectType objtype, List *objnames); + static List *getNamespacesObjectsOids(GrantObjectType objtype, List *nspnames); + static List *getRelationsInNamespace(Oid namespaceId, char relkind); static void expand_col_privileges(List *colnames, Oid table_oid, AclMode this_privileges, AclMode *col_privileges, *************** ExecuteGrantStmt(GrantStmt *stmt) *** 286,292 **** */ istmt.is_grant = stmt->is_grant; istmt.objtype = stmt->objtype; ! istmt.objects = objectNamesToOids(stmt->objtype, stmt->objects); /* all_privs to be filled below */ /* privileges to be filled below */ istmt.col_privs = NIL; /* may get filled below */ --- 288,297 ---- */ istmt.is_grant = stmt->is_grant; istmt.objtype = stmt->objtype; ! if (stmt->is_schema) ! istmt.objects = getNamespacesObjectsOids(stmt->objtype, stmt->objects); ! else ! istmt.objects = objectNamesToOids(stmt->objtype, stmt->objects); /* all_privs to be filled below */ /* privileges to be filled below */ istmt.col_privs = NIL; /* may get filled below */ *************** ExecuteGrantStmt(GrantStmt *stmt) *** 325,330 **** --- 330,336 ---- * the object type. */ case ACL_OBJECT_RELATION: + case ACL_OBJECT_VIEW: all_privileges = ACL_ALL_RIGHTS_RELATION | ACL_ALL_RIGHTS_SEQUENCE; errormsg = gettext_noop("invalid privilege type %s for relation"); break; *************** ExecuteGrantStmt(GrantStmt *stmt) *** 394,400 **** */ if (privnode->cols) { ! if (stmt->objtype != ACL_OBJECT_RELATION) ereport(ERROR, (errcode(ERRCODE_INVALID_GRANT_OPERATION), errmsg("column privileges are only valid for relations"))); --- 400,406 ---- */ if (privnode->cols) { ! if (stmt->objtype != ACL_OBJECT_RELATION && stmt->objtype != ACL_OBJECT_VIEW) ereport(ERROR, (errcode(ERRCODE_INVALID_GRANT_OPERATION), errmsg("column privileges are only valid for relations"))); *************** ExecGrantStmt_oids(InternalGrant *istmt) *** 431,436 **** --- 437,443 ---- switch (istmt->objtype) { case ACL_OBJECT_RELATION: + case ACL_OBJECT_VIEW: case ACL_OBJECT_SEQUENCE: ExecGrant_Relation(istmt); break; *************** objectNamesToOids(GrantObjectType objtyp *** 477,482 **** --- 484,490 ---- switch (objtype) { case ACL_OBJECT_RELATION: + case ACL_OBJECT_VIEW: case ACL_OBJECT_SEQUENCE: foreach(cell, objnames) { *************** objectNamesToOids(GrantObjectType objtyp *** 609,614 **** --- 617,756 ---- return objects; } + + /* + * getNamespacesObjectsOids + * + * Get all objects of a given type from specified schema list into an Oid list. + */ + static List * + getNamespacesObjectsOids(GrantObjectType objtype, List *nspnames) + { + List *objects = NIL; + ListCell *cell; + char *nspname; + Oid namespaceId; + + switch (objtype) + { + case ACL_OBJECT_RELATION: + foreach(cell, nspnames) + { + List *relations = NIL; + + nspname = strVal(lfirst(cell)); + namespaceId = LookupExplicitNamespace(nspname); + + relations = getRelationsInNamespace(namespaceId, RELKIND_RELATION); + + objects = list_concat(objects, relations); + } + break; + case ACL_OBJECT_VIEW: + foreach(cell, nspnames) + { + List *relations = NIL; + + nspname = strVal(lfirst(cell)); + namespaceId = LookupExplicitNamespace(nspname); + + relations = getRelationsInNamespace(namespaceId, RELKIND_VIEW); + + objects = list_concat(objects, relations); + } + break; + case ACL_OBJECT_SEQUENCE: + foreach(cell, nspnames) + { + List *relations = NIL; + + nspname = strVal(lfirst(cell)); + namespaceId = LookupExplicitNamespace(nspname); + + relations = getRelationsInNamespace(namespaceId, RELKIND_SEQUENCE); + + objects = list_concat(objects, relations); + } + break; + case ACL_OBJECT_FUNCTION: + foreach(cell, nspnames) + { + ScanKeyData key[1]; + HeapScanDesc scan; + HeapTuple tuple; + Relation rel; + + nspname = strVal(lfirst(cell)); + namespaceId = LookupExplicitNamespace(nspname); + + ScanKeyInit(&key[0], + Anum_pg_proc_pronamespace, + BTEqualStrategyNumber, F_OIDEQ, + ObjectIdGetDatum(namespaceId)); + + rel = heap_open(ProcedureRelationId, AccessShareLock); + + scan = heap_beginscan(rel, SnapshotNow, 1, key); + + while ((tuple = heap_getnext(scan, ForwardScanDirection)) != NULL) + { + objects = lappend_oid(objects, HeapTupleGetOid(tuple)); + } + + heap_endscan(scan); + + heap_close(rel, AccessShareLock); + } + break; + default: + elog(ERROR, "unrecognized GrantStmt.objtype: %d", + (int) objtype); + } + + return objects; + } + + /* + * getRelationsInNamespace + * + * Return list of relations in given namespace filtered by relation kind + */ + static List * + getRelationsInNamespace(Oid namespaceId, char relkind) + { + List *relations = NIL; + ScanKeyData key[2]; + HeapScanDesc scan; + HeapTuple tuple; + Relation rel; + + ScanKeyInit(&key[0], + Anum_pg_class_relnamespace, + BTEqualStrategyNumber, F_OIDEQ, + ObjectIdGetDatum(namespaceId)); + + ScanKeyInit(&key[1], + Anum_pg_class_relkind, + BTEqualStrategyNumber, F_CHAREQ, + CharGetDatum(relkind)); + + rel = heap_open(RelationRelationId, AccessShareLock); + + scan = heap_beginscan(rel, SnapshotNow, 2, key); + + while ((tuple = heap_getnext(scan, ForwardScanDirection)) != NULL) + { + relations = lappend_oid(relations, HeapTupleGetOid(tuple)); + } + + heap_endscan(scan); + + heap_close(rel, AccessShareLock); + + return relations; + } + + /* * expand_col_privileges * *************** ExecGrant_Relation(InternalGrant *istmt) *** 912,918 **** * permissions. The OR of table and sequence permissions were already * checked. */ ! if (istmt->objtype == ACL_OBJECT_RELATION) { if (pg_class_tuple->relkind == RELKIND_SEQUENCE) { --- 1054,1060 ---- * permissions. The OR of table and sequence permissions were already * checked. */ ! if (istmt->objtype == ACL_OBJECT_RELATION || istmt->objtype == ACL_OBJECT_VIEW) { if (pg_class_tuple->relkind == RELKIND_SEQUENCE) { *************** ExecGrant_Relation(InternalGrant *istmt) *** 986,996 **** aclDatum = SysCacheGetAttr(RELOID, tuple, Anum_pg_class_relacl, &isNull); if (isNull) ! old_acl = acldefault(pg_class_tuple->relkind == RELKIND_SEQUENCE ? ! ACL_OBJECT_SEQUENCE : ACL_OBJECT_RELATION, ! ownerId); else old_acl = DatumGetAclPCopy(aclDatum); /* Need an extra copy of original rel ACL for column handling */ old_rel_acl = aclcopy(old_acl); --- 1128,1150 ---- aclDatum = SysCacheGetAttr(RELOID, tuple, Anum_pg_class_relacl, &isNull); if (isNull) ! { ! switch (pg_class_tuple->relkind) ! { ! case RELKIND_SEQUENCE: ! old_acl = acldefault(ACL_OBJECT_SEQUENCE, ownerId); ! break; ! case RELKIND_VIEW: ! old_acl = acldefault(ACL_OBJECT_VIEW, ownerId); ! break; ! default: ! old_acl = acldefault(ACL_OBJECT_RELATION, ownerId); ! } ! } else + { old_acl = DatumGetAclPCopy(aclDatum); + } /* Need an extra copy of original rel ACL for column handling */ old_rel_acl = aclcopy(old_acl); *************** pg_class_aclmask(Oid table_oid, Oid role *** 2434,2442 **** if (isNull) { /* No ACL, so build default ACL */ ! acl = acldefault(classForm->relkind == RELKIND_SEQUENCE ? ! ACL_OBJECT_SEQUENCE : ACL_OBJECT_RELATION, ! ownerId); aclDatum = (Datum) 0; } else --- 2588,2604 ---- if (isNull) { /* No ACL, so build default ACL */ ! switch (classForm->relkind) ! { ! case RELKIND_SEQUENCE: ! acl = acldefault(ACL_OBJECT_SEQUENCE, ownerId); ! break; ! case RELKIND_VIEW: ! acl = acldefault(ACL_OBJECT_VIEW, ownerId); ! break; ! default: ! acl = acldefault(ACL_OBJECT_RELATION, ownerId); ! } aclDatum = (Datum) 0; } else diff --git a/src/backend/nodes/copyfuncs.c b/src/backend/nodes/copyfuncs.c index 1976648..ac2bd64 100644 *** a/src/backend/nodes/copyfuncs.c --- b/src/backend/nodes/copyfuncs.c *************** _copyGrantStmt(GrantStmt *from) *** 2297,2302 **** --- 2297,2303 ---- COPY_SCALAR_FIELD(is_grant); COPY_SCALAR_FIELD(objtype); + COPY_SCALAR_FIELD(is_schema); COPY_NODE_FIELD(objects); COPY_NODE_FIELD(privileges); COPY_NODE_FIELD(grantees); diff --git a/src/backend/nodes/equalfuncs.c b/src/backend/nodes/equalfuncs.c index 8b466f4..0834199 100644 *** a/src/backend/nodes/equalfuncs.c --- b/src/backend/nodes/equalfuncs.c *************** _equalGrantStmt(GrantStmt *a, GrantStmt *** 979,984 **** --- 979,985 ---- { COMPARE_SCALAR_FIELD(is_grant); COMPARE_SCALAR_FIELD(objtype); + COMPARE_SCALAR_FIELD(is_schema); COMPARE_NODE_FIELD(objects); COMPARE_NODE_FIELD(privileges); COMPARE_NODE_FIELD(grantees); diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y index 858e16c..c3617e7 100644 *** a/src/backend/parser/gram.y --- b/src/backend/parser/gram.y *************** *** 96,101 **** --- 96,102 ---- typedef struct PrivTarget { GrantObjectType objtype; + bool is_schema; List *objs; } PrivTarget; *************** static TypeName *TableFuncTypeName(List *** 465,471 **** EXCLUDING EXCLUSIVE EXECUTE EXISTS EXPLAIN EXTERNAL EXTRACT FALSE_P FAMILY FETCH FIRST_P FLOAT_P FOLLOWING FOR FORCE FOREIGN FORWARD ! FREEZE FROM FULL FUNCTION GLOBAL GRANT GRANTED GREATEST GROUP_P --- 466,472 ---- EXCLUDING EXCLUSIVE EXECUTE EXISTS EXPLAIN EXTERNAL EXTRACT FALSE_P FAMILY FETCH FIRST_P FLOAT_P FOLLOWING FOR FORCE FOREIGN FORWARD ! FREEZE FROM FULL FUNCTION FUNCTIONS GLOBAL GRANT GRANTED GREATEST GROUP_P *************** static TypeName *TableFuncTypeName(List *** 503,515 **** RELATIVE_P RELEASE RENAME REPEATABLE REPLACE REPLICA RESET RESTART RESTRICT RETURNING RETURNS REVOKE RIGHT ROLE ROLLBACK ROW ROWS RULE ! SAVEPOINT SCHEMA SCROLL SEARCH SECOND_P SECURITY SELECT SEQUENCE SERIALIZABLE SERVER SESSION SESSION_USER SET SETOF SHARE SHOW SIMILAR SIMPLE SMALLINT SOME STABLE STANDALONE_P START STATEMENT STATISTICS STDIN STDOUT STORAGE STRICT_P STRIP_P SUBSTRING SUPERUSER_P SYMMETRIC SYSID SYSTEM_P ! TABLE TABLESPACE TEMP TEMPLATE TEMPORARY TEXT_P THEN TIME TIMESTAMP TO TRAILING TRANSACTION TREAT TRIGGER TRIM TRUE_P TRUNCATE TRUSTED TYPE_P --- 504,516 ---- RELATIVE_P RELEASE RENAME REPEATABLE REPLACE REPLICA RESET RESTART RESTRICT RETURNING RETURNS REVOKE RIGHT ROLE ROLLBACK ROW ROWS RULE ! SAVEPOINT SCHEMA SCROLL SEARCH SECOND_P SECURITY SELECT SEQUENCE SEQUENCES SERIALIZABLE SERVER SESSION SESSION_USER SET SETOF SHARE SHOW SIMILAR SIMPLE SMALLINT SOME STABLE STANDALONE_P START STATEMENT STATISTICS STDIN STDOUT STORAGE STRICT_P STRIP_P SUBSTRING SUPERUSER_P SYMMETRIC SYSID SYSTEM_P ! TABLE TABLES TABLESPACE TEMP TEMPLATE TEMPORARY TEXT_P THEN TIME TIMESTAMP TO TRAILING TRANSACTION TREAT TRIGGER TRIM TRUE_P TRUNCATE TRUSTED TYPE_P *************** static TypeName *TableFuncTypeName(List *** 517,523 **** UPDATE USER USING VACUUM VALID VALIDATOR VALUE_P VALUES VARCHAR VARIADIC VARYING ! VERBOSE VERSION_P VIEW VOLATILE WHEN WHERE WHITESPACE_P WINDOW WITH WITHOUT WORK WRAPPER WRITE --- 518,524 ---- UPDATE USER USING VACUUM VALID VALIDATOR VALUE_P VALUES VARCHAR VARIADIC VARYING ! VERBOSE VERSION_P VIEW VIEWS VOLATILE WHEN WHERE WHITESPACE_P WINDOW WITH WITHOUT WORK WRAPPER WRITE *************** GrantStmt: GRANT privileges ON privilege *** 4233,4238 **** --- 4234,4240 ---- n->is_grant = true; n->privileges = $2; n->objtype = ($4)->objtype; + n->is_schema = ($4)->is_schema; n->objects = ($4)->objs; n->grantees = $6; n->grant_option = $7; *************** RevokeStmt: *** 4249,4254 **** --- 4251,4257 ---- n->grant_option = false; n->privileges = $2; n->objtype = ($4)->objtype; + n->is_schema = ($4)->is_schema; n->objects = ($4)->objs; n->grantees = $6; n->behavior = $7; *************** RevokeStmt: *** 4262,4267 **** --- 4265,4271 ---- n->grant_option = true; n->privileges = $5; n->objtype = ($7)->objtype; + n->is_schema = ($7)->is_schema; n->objects = ($7)->objs; n->grantees = $9; n->behavior = $10; *************** privilege_target: *** 4344,4349 **** --- 4348,4354 ---- { PrivTarget *n = (PrivTarget *) palloc(sizeof(PrivTarget)); n->objtype = ACL_OBJECT_RELATION; + n->is_schema = FALSE; n->objs = $1; $$ = n; } *************** privilege_target: *** 4351,4356 **** --- 4356,4370 ---- { PrivTarget *n = (PrivTarget *) palloc(sizeof(PrivTarget)); n->objtype = ACL_OBJECT_RELATION; + n->is_schema = FALSE; + n->objs = $2; + $$ = n; + } + | VIEW qualified_name_list + { + PrivTarget *n = (PrivTarget *) palloc(sizeof(PrivTarget)); + n->objtype = ACL_OBJECT_VIEW; + n->is_schema = FALSE; n->objs = $2; $$ = n; } *************** privilege_target: *** 4358,4363 **** --- 4372,4378 ---- { PrivTarget *n = (PrivTarget *) palloc(sizeof(PrivTarget)); n->objtype = ACL_OBJECT_SEQUENCE; + n->is_schema = FALSE; n->objs = $2; $$ = n; } *************** privilege_target: *** 4365,4370 **** --- 4380,4386 ---- { PrivTarget *n = (PrivTarget *) palloc(sizeof(PrivTarget)); n->objtype = ACL_OBJECT_FDW; + n->is_schema = FALSE; n->objs = $4; $$ = n; } *************** privilege_target: *** 4372,4377 **** --- 4388,4394 ---- { PrivTarget *n = (PrivTarget *) palloc(sizeof(PrivTarget)); n->objtype = ACL_OBJECT_FOREIGN_SERVER; + n->is_schema = FALSE; n->objs = $3; $$ = n; } *************** privilege_target: *** 4379,4384 **** --- 4396,4402 ---- { PrivTarget *n = (PrivTarget *) palloc(sizeof(PrivTarget)); n->objtype = ACL_OBJECT_FUNCTION; + n->is_schema = FALSE; n->objs = $2; $$ = n; } *************** privilege_target: *** 4386,4391 **** --- 4404,4410 ---- { PrivTarget *n = (PrivTarget *) palloc(sizeof(PrivTarget)); n->objtype = ACL_OBJECT_DATABASE; + n->is_schema = FALSE; n->objs = $2; $$ = n; } *************** privilege_target: *** 4393,4398 **** --- 4412,4418 ---- { PrivTarget *n = (PrivTarget *) palloc(sizeof(PrivTarget)); n->objtype = ACL_OBJECT_LANGUAGE; + n->is_schema = FALSE; n->objs = $2; $$ = n; } *************** privilege_target: *** 4400,4405 **** --- 4420,4426 ---- { PrivTarget *n = (PrivTarget *) palloc(sizeof(PrivTarget)); n->objtype = ACL_OBJECT_NAMESPACE; + n->is_schema = FALSE; n->objs = $2; $$ = n; } *************** privilege_target: *** 4407,4415 **** --- 4428,4469 ---- { PrivTarget *n = (PrivTarget *) palloc(sizeof(PrivTarget)); n->objtype = ACL_OBJECT_TABLESPACE; + n->is_schema = FALSE; n->objs = $2; $$ = n; } + | ALL TABLES IN_P name_list + { + PrivTarget *n = (PrivTarget *) palloc(sizeof(PrivTarget)); + n->objtype = ACL_OBJECT_RELATION; + n->is_schema = TRUE; + n->objs = $4; + $$ = n; + } + | ALL VIEWS IN_P name_list + { + PrivTarget *n = (PrivTarget *) palloc(sizeof(PrivTarget)); + n->objtype = ACL_OBJECT_VIEW; + n->is_schema = TRUE; + n->objs = $4; + $$ = n; + } + | ALL SEQUENCES IN_P name_list + { + PrivTarget *n = (PrivTarget *) palloc(sizeof(PrivTarget)); + n->objtype = ACL_OBJECT_SEQUENCE; + n->is_schema = TRUE; + n->objs = $4; + $$ = n; + } + | ALL FUNCTIONS IN_P name_list + { + PrivTarget *n = (PrivTarget *) palloc(sizeof(PrivTarget)); + n->objtype = ACL_OBJECT_FUNCTION; + n->is_schema = TRUE; + n->objs = $4; + $$ = n; + } ; *************** unreserved_keyword: *** 10228,10233 **** --- 10282,10288 ---- | FORCE | FORWARD | FUNCTION + | FUNCTIONS | GLOBAL | GRANTED | HANDLER *************** unreserved_keyword: *** 10337,10342 **** --- 10392,10398 ---- | SECOND_P | SECURITY | SEQUENCE + | SEQUENCES | SERIALIZABLE | SERVER | SESSION *************** unreserved_keyword: *** 10357,10362 **** --- 10413,10419 ---- | SUPERUSER_P | SYSID | SYSTEM_P + | TABLES | TABLESPACE | TEMP | TEMPLATE *************** unreserved_keyword: *** 10381,10386 **** --- 10438,10444 ---- | VARYING | VERSION_P | VIEW + | VIEWS | VOLATILE | WHITESPACE_P | WITHOUT diff --git a/src/backend/utils/adt/acl.c b/src/backend/utils/adt/acl.c index 334823b..ddd92e7 100644 *** a/src/backend/utils/adt/acl.c --- b/src/backend/utils/adt/acl.c *************** acldefault(GrantObjectType objtype, Oid *** 609,614 **** --- 609,615 ---- owner_default = ACL_NO_RIGHTS; break; case ACL_OBJECT_RELATION: + case ACL_OBJECT_VIEW: world_default = ACL_NO_RIGHTS; owner_default = ACL_ALL_RIGHTS_RELATION; break; diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h index 9d53ab9..eab50c3 100644 *** a/src/include/nodes/parsenodes.h --- b/src/include/nodes/parsenodes.h *************** typedef struct AlterDomainStmt *** 1180,1186 **** typedef enum GrantObjectType { ACL_OBJECT_COLUMN, /* column */ ! ACL_OBJECT_RELATION, /* table, view */ ACL_OBJECT_SEQUENCE, /* sequence */ ACL_OBJECT_DATABASE, /* database */ ACL_OBJECT_FDW, /* foreign-data wrapper */ --- 1180,1186 ---- typedef enum GrantObjectType { ACL_OBJECT_COLUMN, /* column */ ! ACL_OBJECT_RELATION, /* table */ ACL_OBJECT_SEQUENCE, /* sequence */ ACL_OBJECT_DATABASE, /* database */ ACL_OBJECT_FDW, /* foreign-data wrapper */ *************** typedef enum GrantObjectType *** 1188,1194 **** ACL_OBJECT_FUNCTION, /* function */ ACL_OBJECT_LANGUAGE, /* procedural language */ ACL_OBJECT_NAMESPACE, /* namespace */ ! ACL_OBJECT_TABLESPACE /* tablespace */ } GrantObjectType; typedef struct GrantStmt --- 1188,1195 ---- ACL_OBJECT_FUNCTION, /* function */ ACL_OBJECT_LANGUAGE, /* procedural language */ ACL_OBJECT_NAMESPACE, /* namespace */ ! ACL_OBJECT_TABLESPACE, /* tablespace */ ! ACL_OBJECT_VIEW, /* view */ } GrantObjectType; typedef struct GrantStmt *************** typedef struct GrantStmt *** 1196,1201 **** --- 1197,1204 ---- NodeTag type; bool is_grant; /* true = GRANT, false = REVOKE */ GrantObjectType objtype; /* kind of object being operated on */ + bool is_schema; /* if true we want all objects + * of objtype in schema */ List *objects; /* list of RangeVar nodes, FuncWithArgs nodes, * or plain names (as Value strings) */ List *privileges; /* list of AccessPriv nodes */ diff --git a/src/include/parser/kwlist.h b/src/include/parser/kwlist.h index 67e9cb4..a6ae56c 100644 *** a/src/include/parser/kwlist.h --- b/src/include/parser/kwlist.h *************** PG_KEYWORD("freeze", FREEZE, TYPE_FUNC_N *** 163,168 **** --- 163,169 ---- PG_KEYWORD("from", FROM, RESERVED_KEYWORD) PG_KEYWORD("full", FULL, TYPE_FUNC_NAME_KEYWORD) PG_KEYWORD("function", FUNCTION, UNRESERVED_KEYWORD) + PG_KEYWORD("functions", FUNCTIONS, UNRESERVED_KEYWORD) PG_KEYWORD("global", GLOBAL, UNRESERVED_KEYWORD) PG_KEYWORD("grant", GRANT, RESERVED_KEYWORD) PG_KEYWORD("granted", GRANTED, UNRESERVED_KEYWORD) *************** PG_KEYWORD("second", SECOND_P, UNRESERVE *** 328,333 **** --- 329,335 ---- PG_KEYWORD("security", SECURITY, UNRESERVED_KEYWORD) PG_KEYWORD("select", SELECT, RESERVED_KEYWORD) PG_KEYWORD("sequence", SEQUENCE, UNRESERVED_KEYWORD) + PG_KEYWORD("sequences", SEQUENCES, UNRESERVED_KEYWORD) PG_KEYWORD("serializable", SERIALIZABLE, UNRESERVED_KEYWORD) PG_KEYWORD("server", SERVER, UNRESERVED_KEYWORD) PG_KEYWORD("session", SESSION, UNRESERVED_KEYWORD) *************** PG_KEYWORD("symmetric", SYMMETRIC, RESER *** 356,361 **** --- 358,364 ---- PG_KEYWORD("sysid", SYSID, UNRESERVED_KEYWORD) PG_KEYWORD("system", SYSTEM_P, UNRESERVED_KEYWORD) PG_KEYWORD("table", TABLE, RESERVED_KEYWORD) + PG_KEYWORD("tables", TABLES, UNRESERVED_KEYWORD) PG_KEYWORD("tablespace", TABLESPACE, UNRESERVED_KEYWORD) PG_KEYWORD("temp", TEMP, UNRESERVED_KEYWORD) PG_KEYWORD("template", TEMPLATE, UNRESERVED_KEYWORD) *************** PG_KEYWORD("varying", VARYING, UNRESERVE *** 396,401 **** --- 399,405 ---- PG_KEYWORD("verbose", VERBOSE, TYPE_FUNC_NAME_KEYWORD) PG_KEYWORD("version", VERSION_P, UNRESERVED_KEYWORD) PG_KEYWORD("view", VIEW, UNRESERVED_KEYWORD) + PG_KEYWORD("views", VIEWS, UNRESERVED_KEYWORD) PG_KEYWORD("volatile", VOLATILE, UNRESERVED_KEYWORD) PG_KEYWORD("when", WHEN, RESERVED_KEYWORD) PG_KEYWORD("where", WHERE, RESERVED_KEYWORD) diff --git a/src/test/regress/expected/privileges.out b/src/test/regress/expected/privileges.out index a17ff59..043c0f3 100644 *** a/src/test/regress/expected/privileges.out --- b/src/test/regress/expected/privileges.out *************** SELECT has_table_privilege('regressuser1 *** 815,820 **** --- 815,849 ---- t (1 row) + -- Grant on all objects of given type in a schema + RESET SESSION AUTHORIZATION; + REVOKE ALL ON ALL TABLES IN public FROM regressuser1; + SELECT has_table_privilege('regressuser1', 'atest1', 'SELECT'); -- false + has_table_privilege + --------------------- + f + (1 row) + + REVOKE ALL ON ALL FUNCTIONS IN public FROM regressuser1; + SET SESSION AUTHORIZATION regressuser1; + SELECT testfunc2(5); -- fail + ERROR: permission denied for function testfunc2 + RESET SESSION AUTHORIZATION; + GRANT ALL ON ALL TABLES IN public TO regressuser1; + SELECT has_table_privilege('regressuser1', 'atest2', 'SELECT'); -- true + has_table_privilege + --------------------- + t + (1 row) + + GRANT ALL ON ALL FUNCTIONS IN public TO regressuser1; + SET SESSION AUTHORIZATION regressuser1; + SELECT testfunc2(5); -- ok + testfunc2 + ----------- + 15 + (1 row) + -- clean up \c DROP FUNCTION testfunc2(int); *************** DROP TABLE atestp2; *** 839,844 **** --- 868,875 ---- DROP GROUP regressgroup1; DROP GROUP regressgroup2; REVOKE USAGE ON LANGUAGE sql FROM regressuser1; + REVOKE ALL ON ALL TABLES IN public FROM regressuser1; + REVOKE ALL ON ALL FUNCTIONS IN public FROM regressuser1; DROP USER regressuser1; DROP USER regressuser2; DROP USER regressuser3; diff --git a/src/test/regress/sql/privileges.sql b/src/test/regress/sql/privileges.sql index 5aa1012..e574c4d 100644 *** a/src/test/regress/sql/privileges.sql --- b/src/test/regress/sql/privileges.sql *************** SELECT has_table_privilege('regressuser3 *** 469,474 **** --- 469,500 ---- SELECT has_table_privilege('regressuser1', 'atest4', 'SELECT WITH GRANT OPTION'); -- true + -- Grant on all objects of given type in a schema + + RESET SESSION AUTHORIZATION; + + REVOKE ALL ON ALL TABLES IN public FROM regressuser1; + + SELECT has_table_privilege('regressuser1', 'atest1', 'SELECT'); -- false + + REVOKE ALL ON ALL FUNCTIONS IN public FROM regressuser1; + + SET SESSION AUTHORIZATION regressuser1; + + SELECT testfunc2(5); -- fail + + RESET SESSION AUTHORIZATION; + + GRANT ALL ON ALL TABLES IN public TO regressuser1; + + SELECT has_table_privilege('regressuser1', 'atest2', 'SELECT'); -- true + + GRANT ALL ON ALL FUNCTIONS IN public TO regressuser1; + + SET SESSION AUTHORIZATION regressuser1; + + SELECT testfunc2(5); -- ok + -- clean up \c *************** DROP GROUP regressgroup1; *** 497,502 **** --- 523,530 ---- DROP GROUP regressgroup2; REVOKE USAGE ON LANGUAGE sql FROM regressuser1; + REVOKE ALL ON ALL TABLES IN public FROM regressuser1; + REVOKE ALL ON ALL FUNCTIONS IN public FROM regressuser1; DROP USER regressuser1; DROP USER regressuser2; DROP USER regressuser3;
One more typo fix in docs -- Regards Petr Jelinek (PJMODOS) diff --git a/doc/src/sgml/ref/grant.sgml b/doc/src/sgml/ref/grant.sgml index bf963b8..6400f9e 100644 *** a/doc/src/sgml/ref/grant.sgml --- b/doc/src/sgml/ref/grant.sgml *************** PostgreSQL documentation *** 23,39 **** <synopsis> GRANT { { SELECT | INSERT | UPDATE | DELETE | TRUNCATE | REFERENCES | TRIGGER } [,...] | ALL [ PRIVILEGES ] } ! ON [ TABLE ] <replaceable class="PARAMETER">tablename</replaceable> [, ...] TO { [ GROUP ] <replaceable class="PARAMETER">rolename</replaceable> | PUBLIC } [, ...] [ WITH GRANT OPTION ] GRANT { { SELECT | INSERT | UPDATE | REFERENCES } ( <replaceable class="PARAMETER">column</replaceable> [, ...] ) [,...] | ALL [ PRIVILEGES ] ( <replaceable class="PARAMETER">column</replaceable> [, ...] ) } ! ON [ TABLE ] <replaceable class="PARAMETER">tablename</replaceable> [, ...] TO { [ GROUP ] <replaceable class="PARAMETER">rolename</replaceable> | PUBLIC } [, ...] [ WITH GRANT OPTION ] GRANT { { USAGE | SELECT | UPDATE } [,...] | ALL [ PRIVILEGES ] } ! ON SEQUENCE <replaceable class="PARAMETER">sequencename</replaceable> [, ...] TO { [ GROUP ] <replaceable class="PARAMETER">rolename</replaceable> | PUBLIC } [, ...] [ WITH GRANT OPTION ] GRANT { { CREATE | CONNECT | TEMPORARY | TEMP } [,...] | ALL [ PRIVILEGES ] } --- 23,41 ---- <synopsis> GRANT { { SELECT | INSERT | UPDATE | DELETE | TRUNCATE | REFERENCES | TRIGGER } [,...] | ALL [ PRIVILEGES ] } ! ON { { [ TABLE | VIEW ] <replaceable class="PARAMETER">tablename</replaceable> [, ...] } ! | ALL [ TABLES | VIEWS ] IN <replaceable class="PARAMETER">schemaname</replaceable> [, ...] } TO { [ GROUP ] <replaceable class="PARAMETER">rolename</replaceable> | PUBLIC } [, ...] [ WITH GRANT OPTION ] GRANT { { SELECT | INSERT | UPDATE | REFERENCES } ( <replaceable class="PARAMETER">column</replaceable> [, ...] ) [,...] | ALL [ PRIVILEGES ] ( <replaceable class="PARAMETER">column</replaceable> [, ...] ) } ! ON [ TABLE | VIEW ] <replaceable class="PARAMETER">tablename</replaceable> [, ...] TO { [ GROUP ] <replaceable class="PARAMETER">rolename</replaceable> | PUBLIC } [, ...] [ WITH GRANT OPTION ] GRANT { { USAGE | SELECT | UPDATE } [,...] | ALL [ PRIVILEGES ] } ! ON { SEQUENCE <replaceable class="PARAMETER">sequencename</replaceable> [, ...] ! | ALL SEQUENCES IN <replaceable class="PARAMETER">schemaname</replaceable> [, ...] } TO { [ GROUP ] <replaceable class="PARAMETER">rolename</replaceable> | PUBLIC } [, ...] [ WITH GRANT OPTION ] GRANT { { CREATE | CONNECT | TEMPORARY | TEMP } [,...] | ALL [ PRIVILEGES ] } *************** GRANT { USAGE | ALL [ PRIVILEGES ] } *** 49,55 **** TO { [ GROUP ] <replaceable class="PARAMETER">rolename</replaceable> | PUBLIC } [, ...] [ WITH GRANT OPTION ] GRANT { EXECUTE | ALL [ PRIVILEGES ] } ! ON FUNCTION <replaceable>funcname</replaceable> ( [ [ <replaceable class="parameter">argmode</replaceable> ] [ <replaceableclass="parameter">argname</replaceable> ] <replaceable class="parameter">argtype</replaceable> [, ...] ] ) [,...] TO { [ GROUP ] <replaceable class="PARAMETER">rolename</replaceable> | PUBLIC } [, ...] [ WITH GRANT OPTION ] GRANT { USAGE | ALL [ PRIVILEGES ] } --- 51,58 ---- TO { [ GROUP ] <replaceable class="PARAMETER">rolename</replaceable> | PUBLIC } [, ...] [ WITH GRANT OPTION ] GRANT { EXECUTE | ALL [ PRIVILEGES ] } ! ON { FUNCTION <replaceable>funcname</replaceable> ( [ [ <replaceable class="parameter">argmode</replaceable> ] [ <replaceableclass="parameter">argname</replaceable> ] <replaceable class="parameter">argtype</replaceable> [, ...] ] ) [,...] ! | ALL FUNCTIONS IN <replaceable class="PARAMETER">schemaname</replaceable> [, ...] } TO { [ GROUP ] <replaceable class="PARAMETER">rolename</replaceable> | PUBLIC } [, ...] [ WITH GRANT OPTION ] GRANT { USAGE | ALL [ PRIVILEGES ] } *************** GRANT <replaceable class="PARAMETER">rol *** 143,148 **** --- 146,159 ---- </para> <para> + There is also the possibility of granting permissions to all objects of + given type inside one or multiple schemas. This functionality is supported + for tables, views, sequences and functions and can done by using + ALL {TABLES|VIEWS|SEQUENCES|FUNCTIONS} IN schemaname syntax in place + of object name. + </para> + + <para> The possible privileges are: <variablelist> diff --git a/doc/src/sgml/ref/revoke.sgml b/doc/src/sgml/ref/revoke.sgml index 8d62580..ac0905f 100644 *** a/doc/src/sgml/ref/revoke.sgml --- b/doc/src/sgml/ref/revoke.sgml *************** PostgreSQL documentation *** 24,44 **** REVOKE [ GRANT OPTION FOR ] { { SELECT | INSERT | UPDATE | DELETE | TRUNCATE | REFERENCES | TRIGGER } [,...] | ALL [ PRIVILEGES ] } ! ON [ TABLE ] <replaceable class="PARAMETER">tablename</replaceable> [, ...] FROM { [ GROUP ] <replaceable class="PARAMETER">rolename</replaceable> | PUBLIC } [, ...] [ CASCADE | RESTRICT ] REVOKE [ GRANT OPTION FOR ] { { SELECT | INSERT | UPDATE | REFERENCES } ( <replaceable class="PARAMETER">column</replaceable> [, ...] ) [,...] | ALL [ PRIVILEGES ] ( <replaceable class="PARAMETER">column</replaceable> [, ...] ) } ! ON [ TABLE ] <replaceable class="PARAMETER">tablename</replaceable> [, ...] FROM { [ GROUP ] <replaceable class="PARAMETER">rolename</replaceable> | PUBLIC } [, ...] [ CASCADE | RESTRICT ] REVOKE [ GRANT OPTION FOR ] { { USAGE | SELECT | UPDATE } [,...] | ALL [ PRIVILEGES ] } ! ON SEQUENCE <replaceable class="PARAMETER">sequencename</replaceable> [, ...] FROM { [ GROUP ] <replaceable class="PARAMETER">rolename</replaceable> | PUBLIC } [, ...] [ CASCADE | RESTRICT ] --- 24,46 ---- REVOKE [ GRANT OPTION FOR ] { { SELECT | INSERT | UPDATE | DELETE | TRUNCATE | REFERENCES | TRIGGER } [,...] | ALL [ PRIVILEGES ] } ! ON { { [ TABLE | VIEW ] <replaceable class="PARAMETER">tablename</replaceable> [, ...] } ! | ALL [ TABLES | VIEWS ] IN <replaceable>schemaname</replaceable> [, ...] } FROM { [ GROUP ] <replaceable class="PARAMETER">rolename</replaceable> | PUBLIC } [, ...] [ CASCADE | RESTRICT ] REVOKE [ GRANT OPTION FOR ] { { SELECT | INSERT | UPDATE | REFERENCES } ( <replaceable class="PARAMETER">column</replaceable> [, ...] ) [,...] | ALL [ PRIVILEGES ] ( <replaceable class="PARAMETER">column</replaceable> [, ...] ) } ! ON [ TABLE | VIEW ] <replaceable class="PARAMETER">tablename</replaceable> [, ...] FROM { [ GROUP ] <replaceable class="PARAMETER">rolename</replaceable> | PUBLIC } [, ...] [ CASCADE | RESTRICT ] REVOKE [ GRANT OPTION FOR ] { { USAGE | SELECT | UPDATE } [,...] | ALL [ PRIVILEGES ] } ! ON { SEQUENCE <replaceable class="PARAMETER">sequencename</replaceable> [, ...] ! | ALL SEQUENCES IN <replaceable>schemaname</replaceable> [, ...] } FROM { [ GROUP ] <replaceable class="PARAMETER">rolename</replaceable> | PUBLIC } [, ...] [ CASCADE | RESTRICT ] *************** REVOKE [ GRANT OPTION FOR ] *** 62,68 **** REVOKE [ GRANT OPTION FOR ] { EXECUTE | ALL [ PRIVILEGES ] } ! ON FUNCTION <replaceable>funcname</replaceable> ( [ [ <replaceable class="parameter">argmode</replaceable> ] [ <replaceableclass="parameter">argname</replaceable> ] <replaceable class="parameter">argtype</replaceable> [, ...] ] ) [,...] FROM { [ GROUP ] <replaceable class="PARAMETER">rolename</replaceable> | PUBLIC } [, ...] [ CASCADE | RESTRICT ] --- 64,71 ---- REVOKE [ GRANT OPTION FOR ] { EXECUTE | ALL [ PRIVILEGES ] } ! ON { FUNCTION <replaceable>funcname</replaceable> ( [ [ <replaceable class="parameter">argmode</replaceable> ] [ <replaceableclass="parameter">argname</replaceable> ] <replaceable class="parameter">argtype</replaceable> [, ...] ] ) [,...] ! | ALL FUNCTIONS IN <replaceable>schemaname</replaceable> [, ...] } FROM { [ GROUP ] <replaceable class="PARAMETER">rolename</replaceable> | PUBLIC } [, ...] [ CASCADE | RESTRICT ] diff --git a/src/backend/catalog/aclchk.c b/src/backend/catalog/aclchk.c index ec4aaf0..0bf4eb1 100644 *** a/src/backend/catalog/aclchk.c --- b/src/backend/catalog/aclchk.c *************** static void ExecGrant_Namespace(Internal *** 61,66 **** --- 61,68 ---- static void ExecGrant_Tablespace(InternalGrant *grantStmt); static List *objectNamesToOids(GrantObjectType objtype, List *objnames); + static List *getNamespacesObjectsOids(GrantObjectType objtype, List *nspnames); + static List *getRelationsInNamespace(Oid namespaceId, char relkind); static void expand_col_privileges(List *colnames, Oid table_oid, AclMode this_privileges, AclMode *col_privileges, *************** ExecuteGrantStmt(GrantStmt *stmt) *** 286,292 **** */ istmt.is_grant = stmt->is_grant; istmt.objtype = stmt->objtype; ! istmt.objects = objectNamesToOids(stmt->objtype, stmt->objects); /* all_privs to be filled below */ /* privileges to be filled below */ istmt.col_privs = NIL; /* may get filled below */ --- 288,297 ---- */ istmt.is_grant = stmt->is_grant; istmt.objtype = stmt->objtype; ! if (stmt->is_schema) ! istmt.objects = getNamespacesObjectsOids(stmt->objtype, stmt->objects); ! else ! istmt.objects = objectNamesToOids(stmt->objtype, stmt->objects); /* all_privs to be filled below */ /* privileges to be filled below */ istmt.col_privs = NIL; /* may get filled below */ *************** ExecuteGrantStmt(GrantStmt *stmt) *** 325,330 **** --- 330,336 ---- * the object type. */ case ACL_OBJECT_RELATION: + case ACL_OBJECT_VIEW: all_privileges = ACL_ALL_RIGHTS_RELATION | ACL_ALL_RIGHTS_SEQUENCE; errormsg = gettext_noop("invalid privilege type %s for relation"); break; *************** ExecuteGrantStmt(GrantStmt *stmt) *** 394,400 **** */ if (privnode->cols) { ! if (stmt->objtype != ACL_OBJECT_RELATION) ereport(ERROR, (errcode(ERRCODE_INVALID_GRANT_OPERATION), errmsg("column privileges are only valid for relations"))); --- 400,406 ---- */ if (privnode->cols) { ! if (stmt->objtype != ACL_OBJECT_RELATION && stmt->objtype != ACL_OBJECT_VIEW) ereport(ERROR, (errcode(ERRCODE_INVALID_GRANT_OPERATION), errmsg("column privileges are only valid for relations"))); *************** ExecGrantStmt_oids(InternalGrant *istmt) *** 431,436 **** --- 437,443 ---- switch (istmt->objtype) { case ACL_OBJECT_RELATION: + case ACL_OBJECT_VIEW: case ACL_OBJECT_SEQUENCE: ExecGrant_Relation(istmt); break; *************** objectNamesToOids(GrantObjectType objtyp *** 477,482 **** --- 484,490 ---- switch (objtype) { case ACL_OBJECT_RELATION: + case ACL_OBJECT_VIEW: case ACL_OBJECT_SEQUENCE: foreach(cell, objnames) { *************** objectNamesToOids(GrantObjectType objtyp *** 609,614 **** --- 617,756 ---- return objects; } + + /* + * getNamespacesObjectsOids + * + * Get all objects of a given type from specified schema list into an Oid list. + */ + static List * + getNamespacesObjectsOids(GrantObjectType objtype, List *nspnames) + { + List *objects = NIL; + ListCell *cell; + char *nspname; + Oid namespaceId; + + switch (objtype) + { + case ACL_OBJECT_RELATION: + foreach(cell, nspnames) + { + List *relations = NIL; + + nspname = strVal(lfirst(cell)); + namespaceId = LookupExplicitNamespace(nspname); + + relations = getRelationsInNamespace(namespaceId, RELKIND_RELATION); + + objects = list_concat(objects, relations); + } + break; + case ACL_OBJECT_VIEW: + foreach(cell, nspnames) + { + List *relations = NIL; + + nspname = strVal(lfirst(cell)); + namespaceId = LookupExplicitNamespace(nspname); + + relations = getRelationsInNamespace(namespaceId, RELKIND_VIEW); + + objects = list_concat(objects, relations); + } + break; + case ACL_OBJECT_SEQUENCE: + foreach(cell, nspnames) + { + List *relations = NIL; + + nspname = strVal(lfirst(cell)); + namespaceId = LookupExplicitNamespace(nspname); + + relations = getRelationsInNamespace(namespaceId, RELKIND_SEQUENCE); + + objects = list_concat(objects, relations); + } + break; + case ACL_OBJECT_FUNCTION: + foreach(cell, nspnames) + { + ScanKeyData key[1]; + HeapScanDesc scan; + HeapTuple tuple; + Relation rel; + + nspname = strVal(lfirst(cell)); + namespaceId = LookupExplicitNamespace(nspname); + + ScanKeyInit(&key[0], + Anum_pg_proc_pronamespace, + BTEqualStrategyNumber, F_OIDEQ, + ObjectIdGetDatum(namespaceId)); + + rel = heap_open(ProcedureRelationId, AccessShareLock); + + scan = heap_beginscan(rel, SnapshotNow, 1, key); + + while ((tuple = heap_getnext(scan, ForwardScanDirection)) != NULL) + { + objects = lappend_oid(objects, HeapTupleGetOid(tuple)); + } + + heap_endscan(scan); + + heap_close(rel, AccessShareLock); + } + break; + default: + elog(ERROR, "unrecognized GrantStmt.objtype: %d", + (int) objtype); + } + + return objects; + } + + /* + * getRelationsInNamespace + * + * Return list of relations in given namespace filtered by relation kind + */ + static List * + getRelationsInNamespace(Oid namespaceId, char relkind) + { + List *relations = NIL; + ScanKeyData key[2]; + HeapScanDesc scan; + HeapTuple tuple; + Relation rel; + + ScanKeyInit(&key[0], + Anum_pg_class_relnamespace, + BTEqualStrategyNumber, F_OIDEQ, + ObjectIdGetDatum(namespaceId)); + + ScanKeyInit(&key[1], + Anum_pg_class_relkind, + BTEqualStrategyNumber, F_CHAREQ, + CharGetDatum(relkind)); + + rel = heap_open(RelationRelationId, AccessShareLock); + + scan = heap_beginscan(rel, SnapshotNow, 2, key); + + while ((tuple = heap_getnext(scan, ForwardScanDirection)) != NULL) + { + relations = lappend_oid(relations, HeapTupleGetOid(tuple)); + } + + heap_endscan(scan); + + heap_close(rel, AccessShareLock); + + return relations; + } + + /* * expand_col_privileges * *************** ExecGrant_Relation(InternalGrant *istmt) *** 912,918 **** * permissions. The OR of table and sequence permissions were already * checked. */ ! if (istmt->objtype == ACL_OBJECT_RELATION) { if (pg_class_tuple->relkind == RELKIND_SEQUENCE) { --- 1054,1060 ---- * permissions. The OR of table and sequence permissions were already * checked. */ ! if (istmt->objtype == ACL_OBJECT_RELATION || istmt->objtype == ACL_OBJECT_VIEW) { if (pg_class_tuple->relkind == RELKIND_SEQUENCE) { *************** ExecGrant_Relation(InternalGrant *istmt) *** 986,996 **** aclDatum = SysCacheGetAttr(RELOID, tuple, Anum_pg_class_relacl, &isNull); if (isNull) ! old_acl = acldefault(pg_class_tuple->relkind == RELKIND_SEQUENCE ? ! ACL_OBJECT_SEQUENCE : ACL_OBJECT_RELATION, ! ownerId); else old_acl = DatumGetAclPCopy(aclDatum); /* Need an extra copy of original rel ACL for column handling */ old_rel_acl = aclcopy(old_acl); --- 1128,1150 ---- aclDatum = SysCacheGetAttr(RELOID, tuple, Anum_pg_class_relacl, &isNull); if (isNull) ! { ! switch (pg_class_tuple->relkind) ! { ! case RELKIND_SEQUENCE: ! old_acl = acldefault(ACL_OBJECT_SEQUENCE, ownerId); ! break; ! case RELKIND_VIEW: ! old_acl = acldefault(ACL_OBJECT_VIEW, ownerId); ! break; ! default: ! old_acl = acldefault(ACL_OBJECT_RELATION, ownerId); ! } ! } else + { old_acl = DatumGetAclPCopy(aclDatum); + } /* Need an extra copy of original rel ACL for column handling */ old_rel_acl = aclcopy(old_acl); *************** pg_class_aclmask(Oid table_oid, Oid role *** 2434,2442 **** if (isNull) { /* No ACL, so build default ACL */ ! acl = acldefault(classForm->relkind == RELKIND_SEQUENCE ? ! ACL_OBJECT_SEQUENCE : ACL_OBJECT_RELATION, ! ownerId); aclDatum = (Datum) 0; } else --- 2588,2604 ---- if (isNull) { /* No ACL, so build default ACL */ ! switch (classForm->relkind) ! { ! case RELKIND_SEQUENCE: ! acl = acldefault(ACL_OBJECT_SEQUENCE, ownerId); ! break; ! case RELKIND_VIEW: ! acl = acldefault(ACL_OBJECT_VIEW, ownerId); ! break; ! default: ! acl = acldefault(ACL_OBJECT_RELATION, ownerId); ! } aclDatum = (Datum) 0; } else diff --git a/src/backend/nodes/copyfuncs.c b/src/backend/nodes/copyfuncs.c index 1976648..ac2bd64 100644 *** a/src/backend/nodes/copyfuncs.c --- b/src/backend/nodes/copyfuncs.c *************** _copyGrantStmt(GrantStmt *from) *** 2297,2302 **** --- 2297,2303 ---- COPY_SCALAR_FIELD(is_grant); COPY_SCALAR_FIELD(objtype); + COPY_SCALAR_FIELD(is_schema); COPY_NODE_FIELD(objects); COPY_NODE_FIELD(privileges); COPY_NODE_FIELD(grantees); diff --git a/src/backend/nodes/equalfuncs.c b/src/backend/nodes/equalfuncs.c index 8b466f4..0834199 100644 *** a/src/backend/nodes/equalfuncs.c --- b/src/backend/nodes/equalfuncs.c *************** _equalGrantStmt(GrantStmt *a, GrantStmt *** 979,984 **** --- 979,985 ---- { COMPARE_SCALAR_FIELD(is_grant); COMPARE_SCALAR_FIELD(objtype); + COMPARE_SCALAR_FIELD(is_schema); COMPARE_NODE_FIELD(objects); COMPARE_NODE_FIELD(privileges); COMPARE_NODE_FIELD(grantees); diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y index 858e16c..c3617e7 100644 *** a/src/backend/parser/gram.y --- b/src/backend/parser/gram.y *************** *** 96,101 **** --- 96,102 ---- typedef struct PrivTarget { GrantObjectType objtype; + bool is_schema; List *objs; } PrivTarget; *************** static TypeName *TableFuncTypeName(List *** 465,471 **** EXCLUDING EXCLUSIVE EXECUTE EXISTS EXPLAIN EXTERNAL EXTRACT FALSE_P FAMILY FETCH FIRST_P FLOAT_P FOLLOWING FOR FORCE FOREIGN FORWARD ! FREEZE FROM FULL FUNCTION GLOBAL GRANT GRANTED GREATEST GROUP_P --- 466,472 ---- EXCLUDING EXCLUSIVE EXECUTE EXISTS EXPLAIN EXTERNAL EXTRACT FALSE_P FAMILY FETCH FIRST_P FLOAT_P FOLLOWING FOR FORCE FOREIGN FORWARD ! FREEZE FROM FULL FUNCTION FUNCTIONS GLOBAL GRANT GRANTED GREATEST GROUP_P *************** static TypeName *TableFuncTypeName(List *** 503,515 **** RELATIVE_P RELEASE RENAME REPEATABLE REPLACE REPLICA RESET RESTART RESTRICT RETURNING RETURNS REVOKE RIGHT ROLE ROLLBACK ROW ROWS RULE ! SAVEPOINT SCHEMA SCROLL SEARCH SECOND_P SECURITY SELECT SEQUENCE SERIALIZABLE SERVER SESSION SESSION_USER SET SETOF SHARE SHOW SIMILAR SIMPLE SMALLINT SOME STABLE STANDALONE_P START STATEMENT STATISTICS STDIN STDOUT STORAGE STRICT_P STRIP_P SUBSTRING SUPERUSER_P SYMMETRIC SYSID SYSTEM_P ! TABLE TABLESPACE TEMP TEMPLATE TEMPORARY TEXT_P THEN TIME TIMESTAMP TO TRAILING TRANSACTION TREAT TRIGGER TRIM TRUE_P TRUNCATE TRUSTED TYPE_P --- 504,516 ---- RELATIVE_P RELEASE RENAME REPEATABLE REPLACE REPLICA RESET RESTART RESTRICT RETURNING RETURNS REVOKE RIGHT ROLE ROLLBACK ROW ROWS RULE ! SAVEPOINT SCHEMA SCROLL SEARCH SECOND_P SECURITY SELECT SEQUENCE SEQUENCES SERIALIZABLE SERVER SESSION SESSION_USER SET SETOF SHARE SHOW SIMILAR SIMPLE SMALLINT SOME STABLE STANDALONE_P START STATEMENT STATISTICS STDIN STDOUT STORAGE STRICT_P STRIP_P SUBSTRING SUPERUSER_P SYMMETRIC SYSID SYSTEM_P ! TABLE TABLES TABLESPACE TEMP TEMPLATE TEMPORARY TEXT_P THEN TIME TIMESTAMP TO TRAILING TRANSACTION TREAT TRIGGER TRIM TRUE_P TRUNCATE TRUSTED TYPE_P *************** static TypeName *TableFuncTypeName(List *** 517,523 **** UPDATE USER USING VACUUM VALID VALIDATOR VALUE_P VALUES VARCHAR VARIADIC VARYING ! VERBOSE VERSION_P VIEW VOLATILE WHEN WHERE WHITESPACE_P WINDOW WITH WITHOUT WORK WRAPPER WRITE --- 518,524 ---- UPDATE USER USING VACUUM VALID VALIDATOR VALUE_P VALUES VARCHAR VARIADIC VARYING ! VERBOSE VERSION_P VIEW VIEWS VOLATILE WHEN WHERE WHITESPACE_P WINDOW WITH WITHOUT WORK WRAPPER WRITE *************** GrantStmt: GRANT privileges ON privilege *** 4233,4238 **** --- 4234,4240 ---- n->is_grant = true; n->privileges = $2; n->objtype = ($4)->objtype; + n->is_schema = ($4)->is_schema; n->objects = ($4)->objs; n->grantees = $6; n->grant_option = $7; *************** RevokeStmt: *** 4249,4254 **** --- 4251,4257 ---- n->grant_option = false; n->privileges = $2; n->objtype = ($4)->objtype; + n->is_schema = ($4)->is_schema; n->objects = ($4)->objs; n->grantees = $6; n->behavior = $7; *************** RevokeStmt: *** 4262,4267 **** --- 4265,4271 ---- n->grant_option = true; n->privileges = $5; n->objtype = ($7)->objtype; + n->is_schema = ($7)->is_schema; n->objects = ($7)->objs; n->grantees = $9; n->behavior = $10; *************** privilege_target: *** 4344,4349 **** --- 4348,4354 ---- { PrivTarget *n = (PrivTarget *) palloc(sizeof(PrivTarget)); n->objtype = ACL_OBJECT_RELATION; + n->is_schema = FALSE; n->objs = $1; $$ = n; } *************** privilege_target: *** 4351,4356 **** --- 4356,4370 ---- { PrivTarget *n = (PrivTarget *) palloc(sizeof(PrivTarget)); n->objtype = ACL_OBJECT_RELATION; + n->is_schema = FALSE; + n->objs = $2; + $$ = n; + } + | VIEW qualified_name_list + { + PrivTarget *n = (PrivTarget *) palloc(sizeof(PrivTarget)); + n->objtype = ACL_OBJECT_VIEW; + n->is_schema = FALSE; n->objs = $2; $$ = n; } *************** privilege_target: *** 4358,4363 **** --- 4372,4378 ---- { PrivTarget *n = (PrivTarget *) palloc(sizeof(PrivTarget)); n->objtype = ACL_OBJECT_SEQUENCE; + n->is_schema = FALSE; n->objs = $2; $$ = n; } *************** privilege_target: *** 4365,4370 **** --- 4380,4386 ---- { PrivTarget *n = (PrivTarget *) palloc(sizeof(PrivTarget)); n->objtype = ACL_OBJECT_FDW; + n->is_schema = FALSE; n->objs = $4; $$ = n; } *************** privilege_target: *** 4372,4377 **** --- 4388,4394 ---- { PrivTarget *n = (PrivTarget *) palloc(sizeof(PrivTarget)); n->objtype = ACL_OBJECT_FOREIGN_SERVER; + n->is_schema = FALSE; n->objs = $3; $$ = n; } *************** privilege_target: *** 4379,4384 **** --- 4396,4402 ---- { PrivTarget *n = (PrivTarget *) palloc(sizeof(PrivTarget)); n->objtype = ACL_OBJECT_FUNCTION; + n->is_schema = FALSE; n->objs = $2; $$ = n; } *************** privilege_target: *** 4386,4391 **** --- 4404,4410 ---- { PrivTarget *n = (PrivTarget *) palloc(sizeof(PrivTarget)); n->objtype = ACL_OBJECT_DATABASE; + n->is_schema = FALSE; n->objs = $2; $$ = n; } *************** privilege_target: *** 4393,4398 **** --- 4412,4418 ---- { PrivTarget *n = (PrivTarget *) palloc(sizeof(PrivTarget)); n->objtype = ACL_OBJECT_LANGUAGE; + n->is_schema = FALSE; n->objs = $2; $$ = n; } *************** privilege_target: *** 4400,4405 **** --- 4420,4426 ---- { PrivTarget *n = (PrivTarget *) palloc(sizeof(PrivTarget)); n->objtype = ACL_OBJECT_NAMESPACE; + n->is_schema = FALSE; n->objs = $2; $$ = n; } *************** privilege_target: *** 4407,4415 **** --- 4428,4469 ---- { PrivTarget *n = (PrivTarget *) palloc(sizeof(PrivTarget)); n->objtype = ACL_OBJECT_TABLESPACE; + n->is_schema = FALSE; n->objs = $2; $$ = n; } + | ALL TABLES IN_P name_list + { + PrivTarget *n = (PrivTarget *) palloc(sizeof(PrivTarget)); + n->objtype = ACL_OBJECT_RELATION; + n->is_schema = TRUE; + n->objs = $4; + $$ = n; + } + | ALL VIEWS IN_P name_list + { + PrivTarget *n = (PrivTarget *) palloc(sizeof(PrivTarget)); + n->objtype = ACL_OBJECT_VIEW; + n->is_schema = TRUE; + n->objs = $4; + $$ = n; + } + | ALL SEQUENCES IN_P name_list + { + PrivTarget *n = (PrivTarget *) palloc(sizeof(PrivTarget)); + n->objtype = ACL_OBJECT_SEQUENCE; + n->is_schema = TRUE; + n->objs = $4; + $$ = n; + } + | ALL FUNCTIONS IN_P name_list + { + PrivTarget *n = (PrivTarget *) palloc(sizeof(PrivTarget)); + n->objtype = ACL_OBJECT_FUNCTION; + n->is_schema = TRUE; + n->objs = $4; + $$ = n; + } ; *************** unreserved_keyword: *** 10228,10233 **** --- 10282,10288 ---- | FORCE | FORWARD | FUNCTION + | FUNCTIONS | GLOBAL | GRANTED | HANDLER *************** unreserved_keyword: *** 10337,10342 **** --- 10392,10398 ---- | SECOND_P | SECURITY | SEQUENCE + | SEQUENCES | SERIALIZABLE | SERVER | SESSION *************** unreserved_keyword: *** 10357,10362 **** --- 10413,10419 ---- | SUPERUSER_P | SYSID | SYSTEM_P + | TABLES | TABLESPACE | TEMP | TEMPLATE *************** unreserved_keyword: *** 10381,10386 **** --- 10438,10444 ---- | VARYING | VERSION_P | VIEW + | VIEWS | VOLATILE | WHITESPACE_P | WITHOUT diff --git a/src/backend/utils/adt/acl.c b/src/backend/utils/adt/acl.c index 334823b..ddd92e7 100644 *** a/src/backend/utils/adt/acl.c --- b/src/backend/utils/adt/acl.c *************** acldefault(GrantObjectType objtype, Oid *** 609,614 **** --- 609,615 ---- owner_default = ACL_NO_RIGHTS; break; case ACL_OBJECT_RELATION: + case ACL_OBJECT_VIEW: world_default = ACL_NO_RIGHTS; owner_default = ACL_ALL_RIGHTS_RELATION; break; diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h index 9d53ab9..eab50c3 100644 *** a/src/include/nodes/parsenodes.h --- b/src/include/nodes/parsenodes.h *************** typedef struct AlterDomainStmt *** 1180,1186 **** typedef enum GrantObjectType { ACL_OBJECT_COLUMN, /* column */ ! ACL_OBJECT_RELATION, /* table, view */ ACL_OBJECT_SEQUENCE, /* sequence */ ACL_OBJECT_DATABASE, /* database */ ACL_OBJECT_FDW, /* foreign-data wrapper */ --- 1180,1186 ---- typedef enum GrantObjectType { ACL_OBJECT_COLUMN, /* column */ ! ACL_OBJECT_RELATION, /* table */ ACL_OBJECT_SEQUENCE, /* sequence */ ACL_OBJECT_DATABASE, /* database */ ACL_OBJECT_FDW, /* foreign-data wrapper */ *************** typedef enum GrantObjectType *** 1188,1194 **** ACL_OBJECT_FUNCTION, /* function */ ACL_OBJECT_LANGUAGE, /* procedural language */ ACL_OBJECT_NAMESPACE, /* namespace */ ! ACL_OBJECT_TABLESPACE /* tablespace */ } GrantObjectType; typedef struct GrantStmt --- 1188,1195 ---- ACL_OBJECT_FUNCTION, /* function */ ACL_OBJECT_LANGUAGE, /* procedural language */ ACL_OBJECT_NAMESPACE, /* namespace */ ! ACL_OBJECT_TABLESPACE, /* tablespace */ ! ACL_OBJECT_VIEW, /* view */ } GrantObjectType; typedef struct GrantStmt *************** typedef struct GrantStmt *** 1196,1201 **** --- 1197,1204 ---- NodeTag type; bool is_grant; /* true = GRANT, false = REVOKE */ GrantObjectType objtype; /* kind of object being operated on */ + bool is_schema; /* if true we want all objects + * of objtype in schema */ List *objects; /* list of RangeVar nodes, FuncWithArgs nodes, * or plain names (as Value strings) */ List *privileges; /* list of AccessPriv nodes */ diff --git a/src/include/parser/kwlist.h b/src/include/parser/kwlist.h index 67e9cb4..a6ae56c 100644 *** a/src/include/parser/kwlist.h --- b/src/include/parser/kwlist.h *************** PG_KEYWORD("freeze", FREEZE, TYPE_FUNC_N *** 163,168 **** --- 163,169 ---- PG_KEYWORD("from", FROM, RESERVED_KEYWORD) PG_KEYWORD("full", FULL, TYPE_FUNC_NAME_KEYWORD) PG_KEYWORD("function", FUNCTION, UNRESERVED_KEYWORD) + PG_KEYWORD("functions", FUNCTIONS, UNRESERVED_KEYWORD) PG_KEYWORD("global", GLOBAL, UNRESERVED_KEYWORD) PG_KEYWORD("grant", GRANT, RESERVED_KEYWORD) PG_KEYWORD("granted", GRANTED, UNRESERVED_KEYWORD) *************** PG_KEYWORD("second", SECOND_P, UNRESERVE *** 328,333 **** --- 329,335 ---- PG_KEYWORD("security", SECURITY, UNRESERVED_KEYWORD) PG_KEYWORD("select", SELECT, RESERVED_KEYWORD) PG_KEYWORD("sequence", SEQUENCE, UNRESERVED_KEYWORD) + PG_KEYWORD("sequences", SEQUENCES, UNRESERVED_KEYWORD) PG_KEYWORD("serializable", SERIALIZABLE, UNRESERVED_KEYWORD) PG_KEYWORD("server", SERVER, UNRESERVED_KEYWORD) PG_KEYWORD("session", SESSION, UNRESERVED_KEYWORD) *************** PG_KEYWORD("symmetric", SYMMETRIC, RESER *** 356,361 **** --- 358,364 ---- PG_KEYWORD("sysid", SYSID, UNRESERVED_KEYWORD) PG_KEYWORD("system", SYSTEM_P, UNRESERVED_KEYWORD) PG_KEYWORD("table", TABLE, RESERVED_KEYWORD) + PG_KEYWORD("tables", TABLES, UNRESERVED_KEYWORD) PG_KEYWORD("tablespace", TABLESPACE, UNRESERVED_KEYWORD) PG_KEYWORD("temp", TEMP, UNRESERVED_KEYWORD) PG_KEYWORD("template", TEMPLATE, UNRESERVED_KEYWORD) *************** PG_KEYWORD("varying", VARYING, UNRESERVE *** 396,401 **** --- 399,405 ---- PG_KEYWORD("verbose", VERBOSE, TYPE_FUNC_NAME_KEYWORD) PG_KEYWORD("version", VERSION_P, UNRESERVED_KEYWORD) PG_KEYWORD("view", VIEW, UNRESERVED_KEYWORD) + PG_KEYWORD("views", VIEWS, UNRESERVED_KEYWORD) PG_KEYWORD("volatile", VOLATILE, UNRESERVED_KEYWORD) PG_KEYWORD("when", WHEN, RESERVED_KEYWORD) PG_KEYWORD("where", WHERE, RESERVED_KEYWORD) diff --git a/src/test/regress/expected/privileges.out b/src/test/regress/expected/privileges.out index a17ff59..043c0f3 100644 *** a/src/test/regress/expected/privileges.out --- b/src/test/regress/expected/privileges.out *************** SELECT has_table_privilege('regressuser1 *** 815,820 **** --- 815,849 ---- t (1 row) + -- Grant on all objects of given type in a schema + RESET SESSION AUTHORIZATION; + REVOKE ALL ON ALL TABLES IN public FROM regressuser1; + SELECT has_table_privilege('regressuser1', 'atest1', 'SELECT'); -- false + has_table_privilege + --------------------- + f + (1 row) + + REVOKE ALL ON ALL FUNCTIONS IN public FROM regressuser1; + SET SESSION AUTHORIZATION regressuser1; + SELECT testfunc2(5); -- fail + ERROR: permission denied for function testfunc2 + RESET SESSION AUTHORIZATION; + GRANT ALL ON ALL TABLES IN public TO regressuser1; + SELECT has_table_privilege('regressuser1', 'atest2', 'SELECT'); -- true + has_table_privilege + --------------------- + t + (1 row) + + GRANT ALL ON ALL FUNCTIONS IN public TO regressuser1; + SET SESSION AUTHORIZATION regressuser1; + SELECT testfunc2(5); -- ok + testfunc2 + ----------- + 15 + (1 row) + -- clean up \c DROP FUNCTION testfunc2(int); *************** DROP TABLE atestp2; *** 839,844 **** --- 868,875 ---- DROP GROUP regressgroup1; DROP GROUP regressgroup2; REVOKE USAGE ON LANGUAGE sql FROM regressuser1; + REVOKE ALL ON ALL TABLES IN public FROM regressuser1; + REVOKE ALL ON ALL FUNCTIONS IN public FROM regressuser1; DROP USER regressuser1; DROP USER regressuser2; DROP USER regressuser3; diff --git a/src/test/regress/sql/privileges.sql b/src/test/regress/sql/privileges.sql index 5aa1012..e574c4d 100644 *** a/src/test/regress/sql/privileges.sql --- b/src/test/regress/sql/privileges.sql *************** SELECT has_table_privilege('regressuser3 *** 469,474 **** --- 469,500 ---- SELECT has_table_privilege('regressuser1', 'atest4', 'SELECT WITH GRANT OPTION'); -- true + -- Grant on all objects of given type in a schema + + RESET SESSION AUTHORIZATION; + + REVOKE ALL ON ALL TABLES IN public FROM regressuser1; + + SELECT has_table_privilege('regressuser1', 'atest1', 'SELECT'); -- false + + REVOKE ALL ON ALL FUNCTIONS IN public FROM regressuser1; + + SET SESSION AUTHORIZATION regressuser1; + + SELECT testfunc2(5); -- fail + + RESET SESSION AUTHORIZATION; + + GRANT ALL ON ALL TABLES IN public TO regressuser1; + + SELECT has_table_privilege('regressuser1', 'atest2', 'SELECT'); -- true + + GRANT ALL ON ALL FUNCTIONS IN public TO regressuser1; + + SET SESSION AUTHORIZATION regressuser1; + + SELECT testfunc2(5); -- ok + -- clean up \c *************** DROP GROUP regressgroup1; *** 497,502 **** --- 523,530 ---- DROP GROUP regressgroup2; REVOKE USAGE ON LANGUAGE sql FROM regressuser1; + REVOKE ALL ON ALL TABLES IN public FROM regressuser1; + REVOKE ALL ON ALL FUNCTIONS IN public FROM regressuser1; DROP USER regressuser1; DROP USER regressuser2; DROP USER regressuser3;
On Fri, Jul 17, 2009 at 9:16 AM, Petr Jelinek<pjmodos@pjmodos.net> wrote: > One more typo fix in docs > > > -- > Regards > Petr Jelinek (PJMODOS) Nikhil, This is still flagged as Needs Review. Are you still reviewing the latest version, or should this be set to ready for committer, or what? ...Robert
Hi, > Nikhil, > > This is still flagged as Needs Review. Are you still reviewing the > latest version, or should this be set to ready for committer, or what? > The review is complete from my side. There is this question about consistency between this patch and the Defaultacls patch. But am ok with this patch on its own. So ready for committer from my side. Regards, Nikhils -- http://www.enterprisedb.com
On Mon, Jul 20, 2009 at 2:12 AM, Nikhil Sontakke<nikhil.sontakke@enterprisedb.com> wrote: > The review is complete from my side. There is this question about > consistency between this patch and the Defaultacls patch. But am ok > with this patch on its own. So ready for committer from my side. My understanding is that this patch will need to be reworked as well based on Tom's comments on "DefaultACLs". Does that sound right? Should we expect a new version this week, or defer this until the September CommitFest? ...Robert
Robert Haas <robertmhaas@gmail.com> writes: > My understanding is that this patch will need to be reworked as well > based on Tom's comments on "DefaultACLs". Does that sound right? > Should we expect a new version this week, or defer this until the > September CommitFest? I was planning to go review that patch too, even though it's presumably not committable yet. I'm not sure whether there is consensus on not using GRANT ON VIEW (ie, having these patches treat tables and views alike). I was waiting to see if Stephen would put forward a convincing counterargument ... regards, tom lane
Tom Lane wrote: > I'm not sure whether there is consensus on not using GRANT ON VIEW > (ie, having these patches treat tables and views alike). I was waiting > to see if Stephen would put forward a convincing counterargument ... > > > Conceptually it is right, I think. A view is a virtual table, so the counter-argument would need to be pretty good ISTM. cheers andrew
On Wed, Aug 5, 2009 at 12:40 PM, Tom Lane<tgl@sss.pgh.pa.us> wrote: > Robert Haas <robertmhaas@gmail.com> writes: >> My understanding is that this patch will need to be reworked as well >> based on Tom's comments on "DefaultACLs". Does that sound right? >> Should we expect a new version this week, or defer this until the >> September CommitFest? > > I was planning to go review that patch too, even though it's presumably > not committable yet. OK, that's good information, thanks. > I'm not sure whether there is consensus on not using GRANT ON VIEW > (ie, having these patches treat tables and views alike). I was waiting > to see if Stephen would put forward a convincing counterargument ... The argument is better for defaults that it is for grant on all, I think, though we also don't want the two to be asymmetric. Defaults need to be really simple to have any value, I think, and avoid violating the POLA. But bulk-grant could be based on object type, object name (with wildcard or regexp pattern), schema membership, or maybe other things, and I think that would be quite useful if we can figure out how to make it clean and elegant. ...Robert
Robert Haas <robertmhaas@gmail.com> writes: > ... bulk-grant could be based on object type, > object name (with wildcard or regexp pattern), schema membership, or > maybe other things, and I think that would be quite useful if we can > figure out how to make it clean and elegant. Yeah. In the end you can always write a plpgsql function that filters on anything at all. The trick is to pick some useful subset of functionality that can be exposed in a less messy way. Or maybe we are going at this the wrong way? Would it be better to try harder to support the write-a-plpgsql-function approach? I don't think the documentation even mentions that approach, let alone provides any concrete examples. It might be interesting to document it and see if there are any simple things we could do to file off rough edges in doing grants that way, rather than implementing what must ultimately be a limited solution directly in GRANT. regards, tom lane
Petr Jelinek <pjmodos@pjmodos.net> writes: > One more typo fix in docs I took a quick look at this version of the patch. Other than the already-mentioned question of whether we really want to create a distinction between tables and views in GRANT, there's not that much there to criticize. I do have a feeling that the implementation is a bit too narrowly focused on the "stuff IN SCHEMA foo" case; if we were ever to add other filtering options it seems like we'd have to rip all this code out and start over. But I don't have any immediate ideas on what it should look like instead. You mentioned that you weren't having any luck making "SCHEMA" optional in the syntax. I'm inclined to think it should be required rather than leave it out entirely. Leaving it out seems like it risks foreclosing future expansion --- are we sure there will never be another selection option that we'd want to start with IN? Putting the search functions (getNamespacesObjectsOids and getRelationsInNamespace) into aclchk.c doesn't seem quite right. I'd have been inclined to put them in namespace.c instead, I think. On the other hand objectNamesToOids hasn't been abstracted at all, so maybe this is fine as-is. Other than that I don't have much to say. I wonder though if this approach isn't sort of a dead-end, and we should instead look at making it easier to build sql or plpgsql functions for doing bulk grants with arbitrary selection conditions. regards, tom lane
Tom Lane wrote: > I do have a feeling that the implementation > is a bit too narrowly focused on the "stuff IN SCHEMA foo" case; > if we were ever to add other filtering options it seems like we'd > have to rip all this code out and start over. But I don't have any > immediate ideas on what it should look like instead. > It is, I was thinking about making that bool is_schema something more useful like int search_option with enum associated with it. But if I do that it would be better to have more then one filter implemented in initial commit - maybe I could add that OWNED BY I was talking about, or do you have better suggestions ? > You mentioned that you weren't having any luck making "SCHEMA" optional > in the syntax. I'm inclined to think it should be required rather than > leave it out entirely. Leaving it out seems like it risks foreclosing > future expansion --- are we sure there will never be another selection > option that we'd want to start with IN? > Ok I'll make it mandatory. > Putting the search functions (getNamespacesObjectsOids and > getRelationsInNamespace) into aclchk.c doesn't seem quite right. > I'd have been inclined to put them in namespace.c instead, I think. > On the other hand objectNamesToOids hasn't been abstracted at all, > so maybe this is fine as-is. > I wanted to be consistent with existing code there (the objectNamesToOids you mentioned) and I also didn't want to export those functions needlessly. > Other than that I don't have much to say. I wonder though if this > approach isn't sort of a dead-end, and we should instead look at > making it easier to build sql or plpgsql functions for doing bulk > grants with arbitrary selection conditions. > The whole reason for me to implement this thing is that I see something like "How can I grant rights to all existing objects in database?" question asked on irc channel like once a week. Most of the time those people only want to use that particular feature once after importing/creating schema so making function you'll only use once is not the optimal way to do it. And more importantly they expect this to be possible using standard SQL. -- Regards Petr Jelinek (PJMODOS)
Tom, > I took a quick look at this version of the patch. Other than the > already-mentioned question of whether we really want to create a > distinction between tables and views in GRANT, there's not that > much there to criticize. It's pretty common to have a database where there are some users who have permissions on views but not on the base tables. So that would be an argument for separating the two. On the other hand, it's not a very persuasive argument; in general, such databases have complex enough security rules that GRANT ALL ON is too simple for them. So, overall, I'd tend to say that we're better off including views and tables in the same GRANT ALL. The purpose of this is to be a simple approach for simple cases, no? > I do have a feeling that the implementation > is a bit too narrowly focused on the "stuff IN SCHEMA foo" case; > if we were ever to add other filtering options it seems like we'd > have to rip all this code out and start over. But I don't have any > immediate ideas on what it should look like instead. Well, schemas do make a good grouping set for objects of different security contexts; they are certainly more reliable than name fragments (as would be supported by a regex scheme). The main defect of schemas is the well-documented issues with managing search_path. > Other than that I don't have much to say. I wonder though if this > approach isn't sort of a dead-end, and we should instead look at > making it easier to build sql or plpgsql functions for doing bulk > grants with arbitrary selection conditions. Right now we have a situation where most web developers aren't using ROLEs *at all* because they are too complex for them to bother with. I literally couldn't count the number of production applications I've run across which connect to Postgres as the superuser. We need a dead-simple approach for the entry-level DB users, and I haven't heard one which is simpler or more approachable than the GRANT ALL + SET DEFAULT approach. With that approach, setting up a 3-role, table only database to have the right security is only 6 statements. I agree that we should also provide examples of how to do this by script in the docs, and maybe even some tools on pgFoundry. But those cover the sophisticated users. For the simple users, we need a dead-simple tool. -- Josh Berkus PostgreSQL Experts Inc. www.pgexperts.com
On Wed, Aug 5, 2009 at 2:57 PM, Josh Berkus<josh@agliodbs.com> wrote: > Right now we have a situation where most web developers aren't using > ROLEs *at all* because they are too complex for them to bother with. I > literally couldn't count the number of production applications I've run > across which connect to Postgres as the superuser. We need a I have one database that is set up with a reporting user (read only on everything). It requires constant maintenance. Every time an object is added or deleted (or dropped and recreated, like a view, which I do ALL THE TIME to work around the inability to add/remove columns) the permissions get shot to hell. I finally crontabbed a script that fixes it every 20 minutes. I had another database where I tried to do some real permission separation and it was just a huge pain in the ass. Grant on all isn't gonna fix these problems completely, but it's a start. The DefaultACL stuff is another important step in the right direction. Documenting how to use PL/pgsql to do this stuff is an EXCELLENT idea, but it's not a complete substitute for providing some usable SQL-level facilities. ...Robert
Robert Haas <robertmhaas@gmail.com> writes: > I have one database that is set up with a reporting user (read only on > everything). It requires constant maintenance. Every time an object > is added or deleted (or dropped and recreated, like a view, which I do > ALL THE TIME to work around the inability to add/remove columns) the > permissions get shot to hell. I finally crontabbed a script that > fixes it every 20 minutes. I had another database where I tried to do > some real permission separation and it was just a huge pain in the > ass. > Grant on all isn't gonna fix these problems completely, but it's a > start. The DefaultACL stuff is another important step in the right > direction. Seems like default ACLs, not grant-on-all, is what you want for that. The idea of better support for plpgsql-driven granting isn't going to compete with default ACLs, but it does compete with grant-on-all. So that's why I'm thinking we ought to take a harder look at that before adding nonstandard extensions to GRANT. Josh's position that "this should be standard SQL" is nonsense, or at least he ought to be making that argument to the standards committee not us. It *isn't* standard, and therefore it's up to us to decide how we want to expose the facility. What's more, syntax extensions to GRANT are a pretty risky way to do it: what if the SQL committee sees the light and SQL:201x includes a GRANT extension, only it conflicts with ours? If we want something built-in, maybe providing some prefab plpgsql functions is the way to go. But we'd have to arrive at a consensus on what best practice of that form looks like. regards, tom lane
On Wed, Aug 5, 2009 at 3:40 PM, Tom Lane<tgl@sss.pgh.pa.us> wrote: > Robert Haas <robertmhaas@gmail.com> writes: >> I have one database that is set up with a reporting user (read only on >> everything). It requires constant maintenance. Every time an object >> is added or deleted (or dropped and recreated, like a view, which I do >> ALL THE TIME to work around the inability to add/remove columns) the >> permissions get shot to hell. I finally crontabbed a script that >> fixes it every 20 minutes. I had another database where I tried to do >> some real permission separation and it was just a huge pain in the >> ass. > >> Grant on all isn't gonna fix these problems completely, but it's a >> start. The DefaultACL stuff is another important step in the right >> direction. > > Seems like default ACLs, not grant-on-all, is what you want for that. Well, that helps with the maintenance, but you also have to set it up initially. There were already 100+ objects in the schema at the time the reporting user was created. ...Robert
2009/8/5 Tom Lane <tgl@sss.pgh.pa.us>: > Robert Haas <robertmhaas@gmail.com> writes: >> I have one database that is set up with a reporting user (read only on >> everything). It requires constant maintenance. Every time an object >> is added or deleted (or dropped and recreated, like a view, which I do >> ALL THE TIME to work around the inability to add/remove columns) the >> permissions get shot to hell. I finally crontabbed a script that >> fixes it every 20 minutes. I had another database where I tried to do >> some real permission separation and it was just a huge pain in the >> ass. > >> Grant on all isn't gonna fix these problems completely, but it's a >> start. The DefaultACL stuff is another important step in the right >> direction. > > Seems like default ACLs, not grant-on-all, is what you want for that. > > The idea of better support for plpgsql-driven granting isn't going > to compete with default ACLs, but it does compete with grant-on-all. > So that's why I'm thinking we ought to take a harder look at that > before adding nonstandard extensions to GRANT. > > Josh's position that "this should be standard SQL" is nonsense, or > at least he ought to be making that argument to the standards committee > not us. It *isn't* standard, and therefore it's up to us to decide how > we want to expose the facility. What's more, syntax extensions to GRANT > are a pretty risky way to do it: what if the SQL committee sees the > light and SQL:201x includes a GRANT extension, only it conflicts with > ours? > > If we want something built-in, maybe providing some prefab plpgsql > functions is the way to go. But we'd have to arrive at a consensus > on what best practice of that form looks like. There are some people, that dislike stored procedures :(. Probably lot of MySQL users. For them are procedures devil still. I would to like some base maintenance library in plpgsql. But it's need plpgsql installed in core by default. Pavel > > regards, tom lane > > -- > Sent via pgsql-hackers mailing list (pgsql-hackers@postgresql.org) > To make changes to your subscription: > http://www.postgresql.org/mailpref/pgsql-hackers >
> Josh's position that "this should be standard SQL" is nonsense, or > at least he ought to be making that argument to the standards committee > not us. Huh? When did I say that? > If we want something built-in, maybe providing some prefab plpgsql > functions is the way to go. But we'd have to arrive at a consensus > on what best practice of that form looks like. *Built-in* functions are just as good as extra syntax, as far as I'm concerned. Functions which require installing plpgsql, reading the docs, creating a function, pasting it in, and saving it are NOT as good; they are unlikely to ever be used, except by the people who didn't really need them in the first place. -- Josh Berkus PostgreSQL Experts Inc. www.pgexperts.com
Josh Berkus <josh@agliodbs.com> writes: >> Josh's position that "this should be standard SQL" is nonsense, or >> at least he ought to be making that argument to the standards committee >> not us. > Huh? When did I say that? Sorry, I think I got one of your messages confused with one of Robert's. Anyway, > *Built-in* functions are just as good as extra syntax, as far as I'm > concerned. > Functions which require installing plpgsql, reading the docs, creating a > function, pasting it in, and saving it are NOT as good; they are > unlikely to ever be used, except by the people who didn't really need > them in the first place. Agreed, whatever we want to provide here should be available in a vanilla installation. This might argue for providing a C-code implementation instead of plpgsql, since I'm not sure we are yet ready to have plpgsql force-installed. But we can certainly design and prototype in plpgsql. regards, tom lane
On Aug 5, 2009, at 4:55 PM, Tom Lane <tgl@sss.pgh.pa.us> wrote: > Josh Berkus <josh@agliodbs.com> writes: >>> Josh's position that "this should be standard SQL" is nonsense, or >>> at least he ought to be making that argument to the standards >>> committee >>> not us. > >> Huh? When did I say that? > > Sorry, I think I got one of your messages confused with one of > Robert's. > Anyway, I don't remember saying that either. SQL I think would be good; standard doesn't matter to me, never mind whether a relevant standard exists. (This is not to say that I think we should deviate wantonly from the standard, only that I have no problem with extensions.) > >> *Built-in* functions are just as good as extra syntax, as far as I'm >> concerned. > >> Functions which require installing plpgsql, reading the docs, >> creating a >> function, pasting it in, and saving it are NOT as good; they are >> unlikely to ever be used, except by the people who didn't really need >> them in the first place. > > Agreed, whatever we want to provide here should be available in a > vanilla installation. This might argue for providing a C-code > implementation instead of plpgsql, since I'm not sure we are yet > ready to have plpgsql force-installed. But we can certainly design > and prototype in plpgsql. ...Robert
* Andrew Dunstan (andrew@dunslane.net) wrote: > Tom Lane wrote: >> I'm not sure whether there is consensus on not using GRANT ON VIEW >> (ie, having these patches treat tables and views alike). I was waiting >> to see if Stephen would put forward a convincing counterargument ... > > Conceptually it is right, I think. A view is a virtual table, so the > counter-argument would need to be pretty good ISTM. With regard to DefaultACL- I don't like just masking out the bits for views at create view time. Right now, a user can 'GRANT INSERT ON <view> TO role;' and it'll actually store insert privs for that view and use them for ON INSERT DO INSTEAD type of work. If we're going to treat them as virtual tables, then we should do that and include all the same permissions that tables get for views. Additionally, this will make it less of a suprise if we support updatable views at some point in the future (we wouldn't have to deal with possibly changing the default acl mask). Personally, I find that I want different controls on views in general. This may stem from my compulsive need for a 'clean' system where I don't want permissions granted on objects that can't support them (eg: views which don't have ON INSERT DO INSTEAD rules). As for changing the default ACL syntax to not be based around SCHEMA- I'm concerned that we'll then have to define some kind of ordering preference if we get away from the defaults being associated with the container object. If we have defaults for users and schemas, which takes precedence? I don't like the idea of trying to merge them. I'm also not really a fan of having the defaults be based on pattern-matching to a relation name, that's just creating another namespace headache, imv. For my needs, the syntax is not of great importance, I'll use what I have to. If ALTER DEFAULT PERMISSIONS is the concensus, then I'd rather at least have it than not have anything. With regard to GRANT ALL- While I don't want to go against the SQL spec, it's opinion is that in 'GRANT SELECT ON TABLE tab1' the 'TABLE' is optional and not relevant. We can keep that and still implement a 'GRANT SELECT ON VIEW tab1' which is limited to only operating on views, allowing admins to be more explicit about what they want. That would at least reduce the disconnect between 'grant on all', 'default acls', and regular GRANT with regard to tables vs. views, presuming we keep them split. I do like the general idea of making it easier to run commands across multiple tables, etc, rather than having 'GRANT ON ALL' syntax. As I believe has been mentioned before, this is a case where we could improve our client tools rather than implement it on the server. For example: \cmd grant select on * to user Of course, our new psql * handling would mean this would grant select on everything in pg_catalog too, at least if we do the same as \d * I've got a simple perl script which does this, and I know others have pl/pgsql functions and the like for doing it. Adding that capability to psql, if we can do it cleanly, would be nice. Adding some kind of 'run-multiple' stored proc is an interesting idea but I'm afraid the users this is really targetting aren't going to appreciate or understand something like: select cmd('grant select on ' || quote_ident(nspname) || '.' || quote_ident(relname) || ' to public') from pg_class join pg_namespace on (pg_class.nspoid = pg_namespace.oid) where pg_namespace.nspname = 'myschema'; Writing a function which takes something like: select grant('SELECT','myschema','*','role'); or takes any kind of actual syntax like: select cmd('grant select on * to role'); just strikes me as forcing users to use a function for the sake of it being a function. I really feel like we should be able to take a page from the unix book here and come up with some way to handle wildcards in certain statements, ala chmod. grant select on * to role; grant select on myschema.* to role; grant select on ab* to role; We don't currently allow "*" in GRANT syntax, and I strongly doubt that the SQL committee will some day allow it AND make it mean something different. If we're really that worried about it, we could have 'GRANTALL' or 'MGRANT' or something. Thanks, Stephen
On Aug 5, 2009, at 11:59 AM, Tom Lane wrote: > Robert Haas <robertmhaas@gmail.com> writes: >> ... bulk-grant could be based on object type, >> object name (with wildcard or regexp pattern), schema membership, or >> maybe other things, and I think that would be quite useful if we can >> figure out how to make it clean and elegant. > > Yeah. In the end you can always write a plpgsql function that filters > on anything at all. The trick is to pick some useful subset of > functionality that can be exposed in a less messy way. > > Or maybe we are going at this the wrong way? Would it be better to > try > harder to support the write-a-plpgsql-function approach? I don't > think > the documentation even mentions that approach, let alone provides any > concrete examples. It might be interesting to document it and see if > there are any simple things we could do to file off rough edges in > doing > grants that way, rather than implementing what must ultimately be a > limited solution directly in GRANT. I'm not sure if this is what you were thinking, but something I've added to all our databases is a simple exec function (see below). This makes it a lot less painful to perform arbitrary operations. Perhaps we should add something similar to the core database? On a related note, I also have tools.raise(level text, messsage text) that allows you to perform a plpgsql RAISE command from sql; I've found that to be very useful in scripts to allow for raising an exception. In this specific case, I think there's enough demand to warrant a built-in mechanism for granting, but if something like exec() is built-in then the bar isn't as high for what the built-in GRANT mechanism needs to handle. CREATE OR REPLACE FUNCTION tools.exec( sql text , echo boolean ) RETURNS text LANGUAGE plpgsql AS $exec$ BEGIN RAISE DEBUG 'Executing dynamic sql: %', sql; EXECUTE sql; IF echo THEN RETURN sql; ELSE RETURN NULL; END IF; END; $exec$; The echo parameter is sometimes useful in scripts so you have some idea what's going on; but it should be optional. -- Decibel!, aka Jim C. Nasby, Database Architect decibel@decibel.org Give your computer some brain candy! www.distributed.net Team #1828
> > \cmd grant select on * to user > when I wrote epsql I implemented \fetchall metastatement. http://okbob.blogspot.com/2009/03/experimental-psql.html It's should be used for GRANT DECLARE x CURSOR FOR SELECT * FROM information_schema.tables .... \fetchall x GRANT ALL ON :table_name TO public; CLOSE x; regards Pavel Stehule > Of course, our new psql * handling would mean this would grant > select on everything in pg_catalog too, at least if we do the same as > \d * > > I've got a simple perl script which does this, and I know others have > pl/pgsql functions and the like for doing it. Adding that capability to > psql, if we can do it cleanly, would be nice. > > Adding some kind of 'run-multiple' stored proc is an interesting idea > but I'm afraid the users this is really targetting aren't going to > appreciate or understand something like: > > select > cmd('grant select on ' > || quote_ident(nspname) > || '.' > || quote_ident(relname) > || ' to public') > from pg_class > join pg_namespace on (pg_class.nspoid = pg_namespace.oid) > where pg_namespace.nspname = 'myschema'; > > Writing a function which takes something like: > select grant('SELECT','myschema','*','role'); > or takes any kind of actual syntax like: > select cmd('grant select on * to role'); > just strikes me as forcing users to use a function for the sake of it > being a function. > > I really feel like we should be able to take a page from the unix book > here and come up with some way to handle wildcards in certain > statements, ala chmod. > > grant select on * to role; > grant select on myschema.* to role; > grant select on ab* to role; > > We don't currently allow "*" in GRANT syntax, and I strongly doubt that > the SQL committee will some day allow it AND make it mean something > different. If we're really that worried about it, we could have > 'GRANTALL' or 'MGRANT' or something. > > Thanks, > > Stephen > > -----BEGIN PGP SIGNATURE----- > Version: GnuPG v1.4.9 (GNU/Linux) > > iEYEARECAAYFAkp69McACgkQrzgMPqB3kii3wQCfUweO4zEIjg2aLd84hxlYGgT1 > pqAAnAnT4FlJkIZ6K3YMjQaCOj3Hww7H > =iUXy > -----END PGP SIGNATURE----- > >
decibel wrote: > In this specific case, I think there's enough demand to warrant a > built-in mechanism for granting, but if something like exec() is > built-in then the bar isn't as high for what the built-in GRANT > mechanism needs to handle. > > CREATE OR REPLACE FUNCTION tools.exec( > sql text > , echo boolean > ) RETURNS text LANGUAGE plpgsql AS $exec$ Perhaps another two functions too: list_all(objtype, schema_pattern, name_pattern) exec_for(objtype, schema_pattern, name_pattern, sql_with_markers) Obviously the third is a simple wrapper around the first two. -- Richard Huxton Archonet Ltd
Stephen Frost wrote: > As for changing the > default ACL syntax to not be based around SCHEMA- I'm concerned that > we'll then have to define some kind of ordering preference if we get > away from the defaults being associated with the container object. If > we have defaults for users and schemas, which takes precedence? I don't > like the idea of trying to merge them. I'm also not really a fan of > having the defaults be based on pattern-matching to a relation name, > that's just creating another namespace headache, imv. > Right, if we make it per user with different types of filters, we'd have to merge them when more then one applies, that might be confusing. > For my needs, the syntax is not of great importance, I'll use what I > have to. If ALTER DEFAULT PERMISSIONS is the concensus, then I'd rather > at least have it than not have anything. > Yeah ALTER DEFAULT PERMISSIONS actually seems like quite reasonable. But we need to have consensus on the filters, either have one (either schema or user based) or have multiple possibilities and then merge them if more then one applies. > While I don't want to go against the SQL spec, it's opinion is that in > 'GRANT SELECT ON TABLE tab1' the 'TABLE' is optional and not relevant. > We can keep that and still implement a 'GRANT SELECT ON VIEW tab1' which > is limited to only operating on views, allowing admins to be more > explicit about what they want. That would at least reduce the > disconnect between 'grant on all', 'default acls', and regular GRANT > with regard to tables vs. views, presuming we keep them split. > Well, reducing confusion between GRANT ON ALL + DefaultACLs and regular GRANT is the whole reason for GRANT ON VIEW. I think we either have to have VIEW in all of them or none of them. > I do like the general idea of making it easier to run commands across > multiple tables, etc, rather than having 'GRANT ON ALL' syntax. As I > believe has been mentioned before, this is a case where we could improve > our client tools rather than implement it on the server. For example: > > \cmd grant select on * to user > > Of course, our new psql * handling would mean this would grant > select on everything in pg_catalog too, at least if we do the same as > \d * > This could be fixed using schema.* maybe if we did this ? > Adding some kind of 'run-multiple' stored proc is an interesting idea > but I'm afraid the users this is really targetting aren't going to > appreciate or understand something like: > > select > cmd('grant select on ' > || quote_ident(nspname) > || '.' > || quote_ident(relname) > || ' to public') > from pg_class > join pg_namespace on (pg_class.nspoid = pg_namespace.oid) > where pg_namespace.nspname = 'myschema'; > Right, something like that goes against the idea of having something simple. GRANT ON ALL was meant to be simple tool for beginners not swiss knife for mass granting. I don't think all new features have to be targeted at advanced dbas or VLDBs. > I really feel like we should be able to take a page from the unix book > here and come up with some way to handle wildcards in certain > statements, ala chmod. > > grant select on * to role; > grant select on myschema.* to role; > grant select on ab* to role; > This syntax would be doable although I am not particularly fond of having that "ab*" option. So, I still don't see consensus on these 3 things. Do we want to differentiate views from tables in these commands or not ? Do we want GRANT ON ALL (or GRANT ON * which is mysql style, btw) in SQL form (not functions or client enhancements) at all ? - if we decide that we don't want to have this as SQL statement then I'll drop the effort. And how do we want to filter default acls ? -- Regards Petr Jelinek (PJMODOS)
I am sorry I forgot to write my opinion on these. > Do we want to differentiate views from tables in these commands or not ? I'd like to have views separate but I don't feel strongly about it. However having single statement for TABLE, VIEW and SEQUENCE is not a good idea IMHO, it will add confusion with standard GRANT statement and I don't think we could call it a TABLE anymore. > Do we want GRANT ON ALL (or GRANT ON * which is mysql style, btw) in > SQL form (not functions or client enhancements) at all ? - if we > decide that we don't want to have this as SQL statement then I'll drop > the effort. Well, since I've written the patch I am for it :) Probably with that GRANT ON * and GRANT ON schema.* as it has indeed very low probability that something like that will be in standard with different meaning and also it's mysql compatible (which is the only db currently having this feature I think), even if that's very little plus. Adding the possibility of running commands on many objects at once in psql would be nice addition in the future, especially since we could have more wild syntax there, but I still feel strongly about having the simplest case handled by SQL. > And how do we want to filter default acls ? My opinion is that the best way to do this would be ALTER DEFAULT PRIVILEGES GRANT ..., without any additional filters, it would just affect the role which runs this command. I think this is best solution because ALTER SCHEMA forces creation of many schemas that might not have anything to do with structure of the database (if you want different default privileges for different things). Also having default privileges per role with filters on various things will IMHO create more confusion than good. And finally if somebody wants to have different default privileges for different things than he can just create child roles with different default privileges and use SET SESSION AUTHORIZATION to switch between them. -- Regards Petr Jelinek (PJMODOS)
> Well, since I've written the patch I am for it :) Probably with that > GRANT ON * and GRANT ON schema.* as it has indeed very low probability > that something like that will be in standard with different meaning and > also it's mysql compatible (which is the only db currently having this > feature I think), even if that's very little plus. I disagree here. While it's nice to be MySQL-compatible, a glob "*" is not at all consistent with other SQL syntax, whereas "ALL" and "GRANT ON ALL IN SCHEMA <schema>" are. The answer as far as the standard is concerned is, why not make an effort to get this into the standard? >> And how do we want to filter default acls ? > My opinion is that the best way to do this would be ALTER DEFAULT > PRIVILEGES GRANT ..., without any additional filters, it would just > affect the role which runs this command. I think this is best solution > because ALTER SCHEMA forces creation of many schemas that might not have > anything to do with structure of the database (if you want different > default privileges for different things). Also having default privileges > per role with filters on various things will IMHO create more confusion > than good. And finally if somebody wants to have different default > privileges for different things than he can just create child roles with > different default privileges and use SET SESSION AUTHORIZATION to switch > between them. I'm not sure if I'm agreeing or disagreeing with you here, but I'll say that it doesn't help a user have a consistent setup for assigning privileges. GRANT ON ALL working per *schema* while ALTER DEFAULT working per *role* will just create confusion and not improve the managability of privileges in PostgreSQL. We need a DEFAULT and a GRANT ALL statement which can be executed on the same scope so that users can easily set up a coherent access control scheme. For my part, I *do* use schema to control my security context for database objects; I find that it's a convenience to be able to take objects which a role has no permissions on out of its visibility (through search_path) as well. And schema-based security mentally maps to directory-based permissions, which unix sysadmins instinctively understand. So I think that a form of GRANT ALL/DEFAULT which supported schema-scoping would be useful to a *lot* more people than one which didn't. I do understand that other scopes (such as scoping by object owner) are equally valid and maybe more consistent with the SQL permissions model.However, I think that role-scoping is not as intuitivelyunderstandible to most users and would be, for that reason, less used and less useful. -- Josh Berkus PostgreSQL Experts Inc. www.pgexperts.com
Josh Berkus wrote: <blockquote cite="mid:4A7DDB39.7020009@agliodbs.com" type="cite"><pre wrap="">I disagree here. Whileit's nice to be MySQL-compatible, a glob "*" is not at all consistent with other SQL syntax, whereas "ALL" and "GRANT ON ALL IN SCHEMA <schema>" are. </pre></blockquote> The * was reaction to Toms fears of standard adding GRANT ON ALL withconflicting meaning, but I don't really see that as relevant point anymore (see my submission of the revised patch).<br/><br /><blockquote cite="mid:4A7DDB39.7020009@agliodbs.com" type="cite"><pre wrap="">The answer as far as thestandard is concerned is, why not make an effort to get this into the standard? </pre></blockquote> We can try :) do we have somebody in the committee ?<br /><br /><blockquotecite="mid:4A7DDB39.7020009@agliodbs.com" type="cite"><blockquote type="cite"><blockquote type="cite"><pre wrap="">Andhow do we want to filter default acls ? </pre></blockquote><pre wrap="">My opinion is that the best way todo this would be ALTER DEFAULT PRIVILEGES GRANT ..., without any additional filters, it would just affect the role which runs this command. I think this is best solution because ALTER SCHEMA forces creation of many schemas that might not have anything to do with structure of the database (if you want different default privileges for different things). Also having default privileges per role with filters on various things will IMHO create more confusion than good. And finally if somebody wants to have different default privileges for different things than he can just create child roles with different default privileges and use SET SESSION AUTHORIZATION to switch between them. </pre></blockquote><pre wrap=""> I'm not sure if I'm agreeing or disagreeing with you here, but I'll say that it doesn't help a user have a consistent setup for assigning privileges. GRANT ON ALL working per *schema* while ALTER DEFAULT working per *role* will just create confusion and not improve the managability of privileges in PostgreSQL. We need a DEFAULT and a GRANT ALL statement which can be executed on the same scope so that users can easily set up a coherent access control scheme. For my part, I *do* use schema to control my security context for database objects; I find that it's a convenience to be able to take objects which a role has no permissions on out of its visibility (through search_path) as well. And schema-based security mentally maps to directory-based permissions, which unix sysadmins instinctively understand. So I think that a form of GRANT ALL/DEFAULT which supported schema-scoping would be useful to a *lot* more people than one which didn't. I do understand that other scopes (such as scoping by object owner) are equally valid and maybe more consistent with the SQL permissions model.However, I think that role-scoping is not as intuitivelyunderstandible to most users and would be, for that reason, less used and less useful. </pre></blockquote> I was discussing this with Stephenand I agree now that schema based filtering is the best way. The role based filtering I proposed would mean user wouldhave to have create role privilege to really take advantage of default acls, also it wouldn't really solve the realworld problems which default acls aims to solve. I also agree on the point that GRANT ON ALL and DEFAULT PRIVILEGES shouldhave same or similar filter.<br /><br /> So currently I see the next step being rewriting the patch for the ALTER DEFAULTPRIVILEGES IN SCHEMA schemaname GRANT ... and leaving the functionality itself unchanged (with the exception of havingVIEW as separate object which I will remove).<br /><br /><pre class="moz-signature" cols="72">-- Regards Petr Jelinek (PJMODOS)</pre>
Hi, I attached revised version of the patch. Changes, thoughts: - SCHEMA is mandatory now - removed VIEWS and GRANT ON VIEW since it looks like only me and Stephen want it there - the patch is now made so that adding new filters in the future won't mean tearing of half of the parser code and replacing it - I decided to go with GRANT ON ALL IN SCHEMA syntax, because I am thinking there is no difference in adding extended syntax to the standard command in GRANT and in SELECT, ALTER TABLE and other commands we extended. And I don't see any way standard could add exactly same syntax for doing something completely different (which is the only way they could break this). -- Regards Petr Jelinek (PJMODOS)
Attachment
Petr Jelinek wrote: > I attached revised version of the patch. Changes, thoughts: > - SCHEMA is mandatory now > - removed VIEWS and GRANT ON VIEW since it looks like only me and > Stephen want it there > - the patch is now made so that adding new filters in the future won't > mean tearing of half of the parser code and replacing it > - I decided to go with GRANT ON ALL IN SCHEMA syntax, because I am > thinking there is no difference in adding extended syntax to the > standard command in GRANT and in SELECT, ALTER TABLE and other > commands we extended. And I don't see any way standard could add > exactly same syntax for doing something completely different (which is > the only way they could break this). Argh, why does this always happen to me ? Immediately after sending the patch I realized there needs to be one more little change done (merging tables and views in the getNamespacesObjectsOids function). -- Regards Petr Jelinek (PJMODOS)
Attachment
On Wednesday 05 August 2009 19:59:52 Tom Lane wrote: > Or maybe we are going at this the wrong way? Would it be better to try > harder to support the write-a-plpgsql-function approach? This would become much simpler if you could just execute plpgsql code instead of having to define a function around it. And perhaps if the plpgsql parser where a bit smarter. Example: RUN LANGUAGE plpgsql $$ FOR schema_name, table_name FROM information_schema.tables WHERE whatever LOOP GRANT ALL ON TABLE schema_name.table_nameTO someuser; END LOOP $$;
Peter Eisentraut <peter_e@gmx.net> wrote: > This would become much simpler if you could just execute plpgsql > code instead of having to define a function around it. I have often wished for that feature. -Kevin
Kevin Grittner wrote: > Peter Eisentraut <peter_e@gmx.net> wrote: > > >> This would become much simpler if you could just execute plpgsql >> code instead of having to define a function around it. >> > > I have often wished for that feature. > > You're not Robinson Crusoe. It could be done in several ways. One fairly simple way would use a new SQL verb (say, DO) like this: DO $$ something in plfoo$ $ LANGUAGE plfoo; We could even default the langauge to plpgsql, for which you would then just need: DO $$ something in plpgsql $$; The something would in effect be treated as a throwaway function taking no parameters and returning void. But to make it really nice you'd have to move away from pl programs as strings. That would be a lot more work, and you really wouldn't want to make it work with more than one PL for the sake of everyone's sanity. cheers andrew
Andrew Dunstan <andrew@dunslane.net> writes: > One fairly simple way would use a new SQL verb (say, DO) like this: > DO $$ something in plfoo $$ LANGUAGE plfoo; Yeah, this has been suggested before. I can't see anything very wrong with it. > We could even default the langauge to plpgsql, for which you would then > just need: > DO $$ something in plpgsql $$; Add a GUC variable to set the default language, perhaps? > But to make it really nice you'd have to move away from pl programs as > strings. That would be a lot more work, and you really wouldn't want to > make it work with more than one PL for the sake of everyone's sanity. That would be an awful lot of messiness to save four keystrokes... regards, tom lane
On Mon, Aug 10, 2009 at 11:36 AM, Tom Lane<tgl@sss.pgh.pa.us> wrote: > Andrew Dunstan <andrew@dunslane.net> writes: >> One fairly simple way would use a new SQL verb (say, DO) like this: > >> DO $$ something in plfoo $$ LANGUAGE plfoo; > > Yeah, this has been suggested before. I can't see anything very wrong > with it. > >> We could even default the langauge to plpgsql, for which you would then >> just need: > >> DO $$ something in plpgsql $$; > > Add a GUC variable to set the default language, perhaps? > >> But to make it really nice you'd have to move away from pl programs as >> strings. That would be a lot more work, and you really wouldn't want to >> make it work with more than one PL for the sake of everyone's sanity. > > That would be an awful lot of messiness to save four keystrokes... I think it would be awfully handy to integrate some of the features of PL/pgsql into core SQL - especially variables, and also things like IF and FOR... but I'm not expecting it to happen any time soon, or maybe ever. ...Robert
2009/8/10 Robert Haas <robertmhaas@gmail.com>: > On Mon, Aug 10, 2009 at 11:36 AM, Tom Lane<tgl@sss.pgh.pa.us> wrote: >> Andrew Dunstan <andrew@dunslane.net> writes: >>> One fairly simple way would use a new SQL verb (say, DO) like this: >> >>> DO $$ something in plfoo $$ LANGUAGE plfoo; >> >> Yeah, this has been suggested before. I can't see anything very wrong >> with it. >> >>> We could even default the langauge to plpgsql, for which you would then >>> just need: >> >>> DO $$ something in plpgsql $$; >> >> Add a GUC variable to set the default language, perhaps? >> >>> But to make it really nice you'd have to move away from pl programs as >>> strings. That would be a lot more work, and you really wouldn't want to >>> make it work with more than one PL for the sake of everyone's sanity. >> >> That would be an awful lot of messiness to save four keystrokes... > > I think it would be awfully handy to integrate some of the features of > PL/pgsql into core SQL - especially variables, and also things like IF > and FOR... but I'm not expecting it to happen any time soon, or maybe > ever. > SQL/PSM is better. This language is developed to integration to SQL. It allows one statement procedures. So IF .. THEN ELSE END IF; isn't correct code for PL/pgSQL and it is correct for SQL/PSM. so FOR r AS SELECT * FROM information_schema.tables DO GRANT .... ON r.table_name TO ...; END FOR; sql/psm doesn't need DECLARE, BEGIN and END in this case; http://www.postgres.cz/index.php/SQL/PSM_Manual regards Pavel Stehule > ...Robert > > -- > Sent via pgsql-hackers mailing list (pgsql-hackers@postgresql.org) > To make changes to your subscription: > http://www.postgresql.org/mailpref/pgsql-hackers >
Tom Lane wrote: > Andrew Dunstan <andrew@dunslane.net> writes: >> But to make it really nice you'd have to move away from pl programs as >> strings. That would be a lot more work, and you really wouldn't want to >> make it work with more than one PL for the sake of everyone's sanity. You mean something like: postgres=# begin ... end; ? > That would be an awful lot of messiness to save four keystrokes... I second that. We support that in EDB for Oracle compatibility, and it's a pain the ass. You need to call the PL/pgSQL parser on the query string just to figure out where it ends. And worse, psql needs to know about it too, so you need a minimal version of the PL/pgSQL parser in the client too. Something like DO $$ begin ...; end $$; gives 90% of the usability with 10% of the trouble. -- Heikki Linnakangas EnterpriseDB http://www.enterprisedb.com
Heikki Linnakangas wrote: > Something like > DO $$ begin ...; end $$; > > gives 90% of the usability with 10% of the trouble. > > Yes, I think that's the consensus. cheers andrew
> Something like > DO $$ begin ...; end $$; > > gives 90% of the usability with 10% of the trouble. I'd be a big fan of this. Especially if we could at an \e for it in psql. \ec? I'm not agreeing, though, that we don't need a GRANT ALL/ALTER DEFAULT.We still need that for the simplest cases so thatnovice-level users will use *some* access control. But it would mean that we wouldn't need GRANT ALL/ALTER DEFAULT to support anything other than the simplest cases. -- Josh Berkus PostgreSQL Experts Inc. www.pgexperts.com
* Josh Berkus (josh@agliodbs.com) wrote: > I'm not agreeing, though, that we don't need a GRANT ALL/ALTER DEFAULT. > We still need that for the simplest cases so that novice-level users > will use *some* access control. But it would mean that we wouldn't need > GRANT ALL/ALTER DEFAULT to support anything other than the simplest cases. I agree with Josh. That's also why I feel the schema or namespace-driven grant/defaults make the most sense. I feel like it's the most natural and intuitive option. Having a default for roles is a neat idea, but I don't believe they'd be used much and would require having a precedence or merging them, neither of which I like. Thanks, Stephen
Hi, Le 10 août 09 à 17:19, Andrew Dunstan a écrit : > One fairly simple way would use a new SQL verb (say, DO) like this: > > DO $$ something in plfoo$ $ LANGUAGE plfoo; > > We could even default the langauge to plpgsql, for which you would > then just need: > > DO $$ something in plpgsql $$; That would also be a nice feature to rely on in extensions install.sql files when you have major version dependant code. Defining a function, calling it then removing it is what to do now. This new syntax would greatly simplify the support code. DO $$ IF postgresql_major_version = '8.2' THEN ... ELSE ... END IF; $$; (of course in this snippet example the ELSE covers it because the CREATE EXTENSION stuff declared e.g. dependancy on postgresql >= 8.2). Regards, -- dim
2009/8/15 Dimitri Fontaine <dfontaine@hi-media.com>: > Hi, > > Le 10 août 09 à 17:19, Andrew Dunstan a écrit : >> >> One fairly simple way would use a new SQL verb (say, DO) like this: >> >> DO $$ something in plfoo$ $ LANGUAGE plfoo; >> >> We could even default the langauge to plpgsql, for which you would then >> just need: >> >> DO $$ something in plpgsql $$; > > That would also be a nice feature to rely on in extensions install.sql files > when you have major version dependant code. Defining a function, calling it > then removing it is what to do now. This new syntax would greatly simplify > the support code. > > DO $$ > IF postgresql_major_version = '8.2' > THEN > ... > > ELSE > ... > > END IF; > $$; why we need DO statement? Why not just $$ $$. Only string literal cannot be statement too, so DO is unnecessary. it can look like: $$ FOR r IN SELECT .... END LOOP; $$; ??? > > (of course in this snippet example the ELSE covers it because the CREATE > EXTENSION stuff declared e.g. dependancy on postgresql >= 8.2). > > Regards, > -- > dim > > > -- > Sent via pgsql-hackers mailing list (pgsql-hackers@postgresql.org) > To make changes to your subscription: > http://www.postgresql.org/mailpref/pgsql-hackers >
Pavel Stehule wrote: > why we need DO statement? Why not just $$ $$. Only string literal > cannot be statement too, so DO is unnecessary. > > it can look like: > > $$ > FOR r IN SELECT .... > END LOOP; > $$; > > ??? > > Well, it's arguably somewhat un-SQL-ish. Every command in SQL is introduced by a keyword verb. I'm also not sure I want to be trying to execute any arbitrary string that accidentally gets placed there because someone forgot to put a keyword or accidentally deleted it. But I'm not too dogmatic on the subject. What do others think? cheers andrew
2009/8/15 Andrew Dunstan <andrew@dunslane.net>: > > > Pavel Stehule wrote: >> >> why we need DO statement? Why not just $$ $$. Only string literal >> cannot be statement too, so DO is unnecessary. >> >> it can look like: >> >> $$ >> FOR r IN SELECT .... >> END LOOP; >> $$; >> >> ??? >> >> > > Well, it's arguably somewhat un-SQL-ish. Every command in SQL is introduced > by a keyword verb. sure - this is not SQL statement. I thing so most SQL-ish is T-SQL style. You have integrated procedural statements. so the best is directly: FOR .... LOOP END LOOP; but it's far future :) > > I'm also not sure I want to be trying to execute any arbitrary string that > accidentally gets placed there because someone forgot to put a keyword or > accidentally deleted it. > > But I'm not too dogmatic on the subject. What do others think? > > cheers > > andrew > >
Andrew Dunstan <andrew@dunslane.net> writes: > Pavel Stehule wrote: >> why we need DO statement? Why not just $$ $$. Only string literal >> cannot be statement too, so DO is unnecessary. > I'm also not sure I want to be trying to execute any arbitrary string > that accidentally gets placed there because someone forgot to put a > keyword or accidentally deleted it. That's my feeling as well. Also, I don't think it is sane to allow options (like "LANGUAGE foo") on a standalone string constant. Yeah, we could persuade bison to do it, but that doesn't make it a good idea. regards, tom lane
> I'm also not sure I want to be trying to execute any arbitrary string > that accidentally gets placed there because someone forgot to put a > keyword or accidentally deleted it. > > But I'm not too dogmatic on the subject. What do others think? Given that $$ is also used to quote non-procedural strings, I don't like the idea that psql would be trying to execute any string I gave it after forgetting "select". If nothing else, that would lead to confusing and misleading error messages. Ideally, we'd be able to execute *any* PL that way by setting a shell variable: \pl plperl DO $f$ foreach ( @_ ) { ... -- Josh Berkus PostgreSQL Experts Inc. www.pgexperts.com
Le 15 août 09 à 22:49, Josh Berkus a écrit : > Ideally, we'd be able to execute *any* PL that way by setting a shell > variable: > > \pl plperl > DO $f$ foreach ( @_ ) { ... Nitpicking dept, I think I prefer: DO [ [LANGUAGE] language] $$ ... $$; DO plperl $$ ... $$; DO language plpython $$ ... $$; language is optional and defaults to plpgsql. Regards, -- dim
On Sat, Aug 15, 2009 at 11:34:04PM +0200, Dimitri Fontaine wrote: > Nitpicking dept, I think I prefer: > > DO [ [LANGUAGE] language] $$ ... $$; > DO plperl $$ ... $$; > DO language plpython $$ ... $$; > > language is optional and defaults to plpgsql. Yup, sounds nicer. The less globals the better! Next all you need is to be able to PREPARE them (and somehow access the parameters from execute) and you'll have nice local functions. :) -- Sam http://samason.me.uk/
Josh Berkus wrote: >> I'm also not sure I want to be trying to execute any arbitrary string >> that accidentally gets placed there because someone forgot to put a >> keyword or accidentally deleted it. >> >> But I'm not too dogmatic on the subject. What do others think? >> > > Given that $$ is also used to quote non-procedural strings, I don't like > the idea that psql would be trying to execute any string I gave it after > forgetting "select". If nothing else, that would lead to confusing and > misleading error messages. > > Ideally, we'd be able to execute *any* PL that way by setting a shell > variable: > > \pl plperl > DO $f$ foreach ( @_ ) { ... > > > I think you have misunderstood. I am not talking at all about doing this in psql. It would be built into the server's SQL so you could use any client, and the default language would be a GUC as Tom suggested upstream. cheers andrew
On lör, 2009-08-15 at 23:31 +0100, Sam Mason wrote: > On Sat, Aug 15, 2009 at 11:34:04PM +0200, Dimitri Fontaine wrote: > > Nitpicking dept, I think I prefer: > > > > DO [ [LANGUAGE] language] $$ ... $$; > > DO plperl $$ ... $$; > > DO language plpython $$ ... $$; > > > > language is optional and defaults to plpgsql. > > Yup, sounds nicer. The less globals the better! > > Next all you need is to be able to PREPARE them (and somehow access the > parameters from execute) and you'll have nice local functions. :) Yeah, rather than just making up some new command for "execute this string", this could be generalized as lambda expressions that could be called whereever an expression is allowed. E.g. SELECT LAMBDA $$ ... $$; -- if CALL is implemented CALL LAMBDA $$ ... $$; PREPARE foo AS SELECT LAMBDA $$ ... $$; EXECUTE foo; SELECT (LAMBDA (x int, y text) $$ ... $$) (37, 'foo');
On Sun, Aug 16, 2009 at 02:15:39AM +0300, Peter Eisentraut wrote: > On 2009-08-15 at 23:31 +0100, Sam Mason wrote: > > Next all you need is to be able to PREPARE them (and somehow access the > > parameters from execute) and you'll have nice local functions. :) > > Yeah, rather than just making up some new command for "execute this > string", this could be generalized as lambda expressions that could be > called whereever an expression is allowed. E.g. > > SELECT LAMBDA $$ ... $$; [..] > SELECT (LAMBDA (x int, y text) $$ ... $$) (37, 'foo'); I can't quite tell if you're being serious or not, you realize that this leaves open the possibility of doing: SELECT t.n, f.op, f.fn(t.n) FROM generate_series(1,10) t(n), (VALUES ('id',LAMBDA (_x int) $$ BEGIN; RETURN _x; END;$$), ('*2',LAMBDA (_x int) $$ BEGIN; RETURN _x*2; END; $$)) f(op,fn) And of storing lambda abstractions in tables? -- Sam http://samason.me.uk/
On Sat, Aug 15, 2009 at 7:15 PM, Peter Eisentraut<peter_e@gmx.net> wrote: > On lör, 2009-08-15 at 23:31 +0100, Sam Mason wrote: >> On Sat, Aug 15, 2009 at 11:34:04PM +0200, Dimitri Fontaine wrote: >> > Nitpicking dept, I think I prefer: >> > >> > DO [ [LANGUAGE] language] $$ ... $$; >> > DO plperl $$ ... $$; >> > DO language plpython $$ ... $$; >> > >> > language is optional and defaults to plpgsql. >> >> Yup, sounds nicer. The less globals the better! >> >> Next all you need is to be able to PREPARE them (and somehow access the >> parameters from execute) and you'll have nice local functions. :) > > Yeah, rather than just making up some new command for "execute this > string", this could be generalized as lambda expressions that could be > called whereever an expression is allowed. E.g. > > SELECT LAMBDA $$ ... $$; > > -- if CALL is implemented > CALL LAMBDA $$ ... $$; > > PREPARE foo AS SELECT LAMBDA $$ ... $$; > EXECUTE foo; > > SELECT (LAMBDA (x int, y text) $$ ... $$) (37, 'foo'); I like this idea (although it might not be too easy to implement, not sure), but I think we could still use DO (which is shorter) for the verb. Lambda-calculus is cool, but "do" is nice and simple. ...Robert
Robert Haas wrote: > > I like this idea (although it might not be too easy to implement, not > sure), but I think we could still use DO (which is shorter) for the > verb. Lambda-calculus is cool, but "do" is nice and simple. > > > SQL is not Lisp. Simple is good. I didn't think Peter was really very serious. cheers andrew
On sön, 2009-08-16 at 00:04 -0400, Andrew Dunstan wrote: > SQL is not Lisp. Simple is good. I didn't think Peter was really very > serious. Well, I don't know if we really need to call it "lambda", but I fully expect to be able to use these "ad hoc functions" as part of other expressions. So making DO or whatever a top-level command that does not integrate with anything else would not really satisfy me.
2009/8/16 Peter Eisentraut <peter_e@gmx.net>: > On sön, 2009-08-16 at 00:04 -0400, Andrew Dunstan wrote: >> SQL is not Lisp. Simple is good. I didn't think Peter was really very >> serious. > > Well, I don't know if we really need to call it "lambda", but I fully > expect to be able to use these "ad hoc functions" as part of other > expressions. So making DO or whatever a top-level command that does not > integrate with anything else would not really satisfy me. > +1 Pavel > > -- > Sent via pgsql-hackers mailing list (pgsql-hackers@postgresql.org) > To make changes to your subscription: > http://www.postgresql.org/mailpref/pgsql-hackers >
On Sun, Aug 16, 2009 at 03:57:08PM +0300, Peter Eisentraut wrote: > On 2009-08-16 at 00:04 -0400, Andrew Dunstan wrote: > > SQL is not Lisp. Simple is good. I didn't think Peter was really very > > serious. > > Well, I don't know if we really need to call it "lambda", but I fully > expect to be able to use these "ad hoc functions" as part of other > expressions. So making DO or whatever a top-level command that does not > integrate with anything else would not really satisfy me. Wow, I didn't think you were serious either! One thing that would make my life easier would be easier one-off custom aggregations, this would seem to be a nice stepping stone towards that. For instance the following "agg" function would have similar semantics to "fold", as found in functional languages. SELECT agg(LAMBDA (text,text) $$ SELECT $1||coalesce($2,''); $$, '', s) FROM (VALUES ('aa'), ('bb')) x(s); I'd expect to get 'aabb' back if I've done something wrong/it's not obvious. I.e. the first parameter is like the SFUNC in CREATE AGGREGATE, the second parameter ('') is the INITCOND, and the third param (s) is what you want to aggregate. You've now got two type variables in play and hence you'd want some better support of parametric polymorphism than PG currently makes easy. The current AGGREGATE infrastructure seems to get away with it by bundling this type knowledge into the aggregate itself. Also, why isn't SQL the default language--plpgsql still needs to be explicitly added doesn't it? -- Sam http://samason.me.uk/
Peter Eisentraut <peter_e@gmx.net> writes: > On sön, 2009-08-16 at 00:04 -0400, Andrew Dunstan wrote: >> SQL is not Lisp. Simple is good. I didn't think Peter was really very >> serious. > Well, I don't know if we really need to call it "lambda", but I fully > expect to be able to use these "ad hoc functions" as part of other > expressions. Why would you expect that? To be used in an expression, you'd also need decoration to tell the function argument types, result type, volatility properties, etc etc (your proposed lambda notation is far too simplistic). I think you're moving the goalposts to a point where we'd need ANOTHER, simpler, mechanism to accomplish the original intent. And frankly, all of the user demand I've heard is for the latter not the former. By the time you get into specifying function properties you might as well just create a function. regards, tom lane
On Sat, Aug 15, 2009 at 11:34:04PM +0200, Dimitri Fontaine wrote: > Nitpicking dept, I think I prefer: > > DO [ [LANGUAGE] language] $$ ... $$; > DO plperl $$ ... $$; > DO language plpython $$ ... $$; > > language is optional and defaults to plpgsql. +1 -dg -- David Gould daveg@sonic.net 510 536 1443 510 282 0869 If simplicity worked, the world would be overrun with insects.
On Sun, Aug 16, 2009 at 02:59:53PM +0200, Pavel Stehule wrote: > 2009/8/16 Peter Eisentraut <peter_e@gmx.net>: > > On sön, 2009-08-16 at 00:04 -0400, Andrew Dunstan wrote: > >> SQL is not Lisp. Simple is good. I didn't think Peter was really very > >> serious. > > > > Well, I don't know if we really need to call it "lambda", but I fully > > expect to be able to use these "ad hoc functions" as part of other > > expressions. So making DO or whatever a top-level command that does not > > integrate with anything else would not really satisfy me. > > +1 +1 -dg -- David Gould daveg@sonic.net 510 536 1443 510 282 0869 If simplicity worked, the world would be overrun with insects.
Tom Lane napsal(a): > Peter Eisentraut <peter_e@gmx.net> writes: >> Well, I don't know if we really need to call it "lambda", but I fully >> expect to be able to use these "ad hoc functions" as part of other >> expressions. > > Why would you expect that? To be used in an expression, you'd also need > decoration to tell the function argument types, result type, volatility > properties, etc etc (your proposed lambda notation is far too > simplistic). I think you're moving the goalposts to a point where we'd > need ANOTHER, simpler, mechanism to accomplish the original intent. > And frankly, all of the user demand I've heard is for the latter not > the former. By the time you get into specifying function properties > you might as well just create a function. > I agree with Tom here, doing it the way Andrew and Tom agreed on will be *way* easier and will give us most of the benefit (as Heikki said "90% of the usability with 10% of the trouble"). I volunteer to do this feature too. The implementation as I see it would create function in pg_temp namespace, call it and then drop it. Any other implementation would imho mean rewriting procedure language api. I am unsure if we should try to make the name of the function unique, since it should not collide with anything if we allow just one statement at a time (transactional DDL wins again), or am I mistaken here ? Also do we want the LANGUAGE option to be at start or at the end or anywhere (like it's in CREATE FUNCTION). The reason I am asking this is that if we let user to put it on both sides then the LANGUAGE keyword can't be optional (what Dimitri Fontaine wanted). And last thing I am wondering is if we want to allow DO to return rows (probably by creating the function with SETOF record as return type) ? I am guessing not here since if user wants to run something often then he should crate a function. Otherwise this should be quite straightforward (I have working code already). -- Regards Petr Jelinek (PJMODOS)
Petr Jelinek wrote: > The implementation as I see it would create function in pg_temp > namespace, call it and then drop it. Any other implementation would > imho mean rewriting procedure language api. That's really ugly. It'll cause catalog bloat with every execution. I think it would be acceptable to have a new column in pg_language that pointed to an anonymous block execute function. Languages that do not define this function cannot use this new feature. BTW I think you should start a new thread for this proposal. It has diverged a bit from GRANT ON ALL. -- Alvaro Herrera http://www.CommandPrompt.com/ The PostgreSQL Company - Command Prompt, Inc.
Alvaro Herrera <alvherre@commandprompt.com> writes: > Petr Jelinek wrote: >> The implementation as I see it would create function in pg_temp >> namespace, call it and then drop it. Any other implementation would >> imho mean rewriting procedure language api. > That's really ugly. It'll cause catalog bloat with every execution. > I think it would be acceptable to have a new column in pg_language that > pointed to an anonymous block execute function. Languages that do not > define this function cannot use this new feature. +1. The other way would also (presumably) mean invoking the language's validate procedure, which might well be redundant and in any case would probably not have exactly the error-reporting behavior one would want. I think it's better if the language knows it's dealing with an anonymous block. You could even imagine the language relaxing its rules a bit, for instance not requiring an outer BEGIN/END in plpgsql. regards, tom lane
Tom Lane napsal(a): <blockquote cite="mid:3493.1250864810@sss.pgh.pa.us" type="cite"><blockquote type="cite"><pre wrap="">That'sreally ugly. It'll cause catalog bloat with every execution. I think it would be acceptable to have a new column in pg_language that pointed to an anonymous block execute function. Languages that do not define this function cannot use this new feature. </pre></blockquote><pre wrap=""> +1. The other way would also (presumably) mean invoking the language's validate procedure, which might well be redundant and in any case would probably not have exactly the error-reporting behavior one would want. I think it's better if the language knows it's dealing with an anonymous block. You could even imagine the language relaxing its rules a bit, for instance not requiring an outer BEGIN/END in plpgsql. </pre></blockquote><br /> Alright I can do it this way.<br /> Howeverthere is one question about implementing it in plpgsql. Currently, the compiler reads info directly from heap tuple,so I either have to write separate compiler for inline functions or change the existing one to accept the requiredinfo as parameters and "fabricate" some of it when compiling inline function. I am unsure which one is the preferredway.<br /><pre class="moz-signature" cols="72">-- Regards Petr Jelinek (PJMODOS)</pre>
Petr Jelinek <pjmodos@pjmodos.net> writes: > However there is one question about implementing it in plpgsql. > Currently, the compiler reads info directly from heap tuple, so I either > have to write separate compiler for inline functions or change the > existing one to accept the required info as parameters and "fabricate" > some of it when compiling inline function. I am unsure which one is the > preferred way. Sounds like we have to refactor that code a bit. Or maybe it should just be a separate code path. The current plpgsql compiler is also pretty intertwined with stuffing all the information about the function into a persistent memory context, which is something we most definitely *don't* want for an anonymous code block. So it's going to take a bit of work there. I think pulling the heap tuple apart might be the least of your worries. regards, tom lane
Tom Lane napsal(a): <blockquote cite="mid:11481.1250892674@sss.pgh.pa.us" type="cite"><pre wrap="">Petr Jelinek <a class="moz-txt-link-rfc2396E"href="mailto:pjmodos@pjmodos.net"><pjmodos@pjmodos.net></a> writes: </pre><blockquotetype="cite"><pre wrap="">However there is one question about implementing it in plpgsql. Currently, the compiler reads info directly from heap tuple, so I either have to write separate compiler for inline functions or change the existing one to accept the required info as parameters and "fabricate" some of it when compiling inline function. I am unsure which one is the preferred way. </pre></blockquote><pre wrap=""> Sounds like we have to refactor that code a bit. Or maybe it should just be a separate code path. The current plpgsql compiler is also pretty intertwined with stuffing all the information about the function into a persistent memory context, which is something we most definitely *don't* want for an anonymous code block. So it's going to take a bit of work there. I think pulling the heap tuple apart might be the least of your worries. </pre></blockquote><br /> The question is still valid, though it's better put in your words - do we wantto refactor the existing compiler or write a separate one ?<br /> About putting the information about the function intoa persistent memory context - I was planning on bypassing it and it can be easily bypassed with both implementations,since plpgsql_compile won't be called even if we do the refactoring. When I talked about modifying currentcompiler I was talking about do_compile only (that's why I talked about the heap tuple). It's true that we don't needmost of the PLpgSQL_function struct for anonymous code block and there might be other advantages in using separate compilerand exec functions for this.<br /><br /><pre class="moz-signature" cols="72">-- Regards Petr Jelinek (PJMODOS)</pre>
> The question is still valid, though it's better put in your words - do > we want to refactor the existing compiler or write a separate one ? So, for now I went with the path of custom compiler and current executor. I attached current version of the patch. I don't expect this to get committed or anything, but I'd like other eyes to take a look at it. What it does: Adds laninline Oid which points to function handling inline code (aka anonymous code block). Adds DO $$some code$$ [ LANGUAGE lanname ] syntax which sends the source code to that laninline function of the specified language (or language set by default_do_language guc). There is implementation for plpgsql with simpler compiler which still creates function struct for the executor (I believe there is no harm in adjusting executor later, when current one works, just does unnecessary stuff). There is doc and a simple regression test for plpgsql implementation. -- Regards Petr Jelinek (PJMODOS)
Attachment
Hi Dimitri, The commitfest app has you listed as the reviewer for this patch. Any progress on your review? Cheers, BJ
Brendan Jurd <direvus@gmail.com> writes: > The commitfest app has you listed as the reviewer for this patch. Any > progress on your review? Funny I just sent a mail to rrr explaining I don't think I'll be able to complete my review until next Thursday. Feel free to steal me the patch if you want to, as I'm planning to start on Monday only... Regards, -- dim
Hi, Petr Jelinek <pjmodos@pjmodos.net> writes: > I attached current version of the patch. I don't expect this to get > committed or anything, but I'd like other eyes to take a look at it. I'm reviewing this patch, and have early questions that might allow for a quick returned with little feedback and much work... Patch applies cleanly and build cleanly too, basic examples are working fine. The problem is the following: dim=# do $$begin select 'foo'; end;$$; ERROR: query has no destination for result data HINT: If you want to discard the results of a SELECT, use PERFORM instead. CONTEXT: PL/pgSQL function "inline" line 1 at SQL statement Here's an example not so simple as to being meaningless: do $$ declare v text := current_setting('server_version'); begin case when v ~ '8.5' then select 'foo'; else select 'bar';end case; end;$$; And while this works: dim=# do $$ declare i integer; begin for i in 1..10 loop raise notice '%', i; end loop; end;$$; One might want to have this working too: do returns setof integer as $$declare i integer; begin for i in 1..10 loop return next; end;$$; So here are the major points about this patch: - it's missing the returns declaration syntax (default value could be returns void?) - it would be much more friendly to users if it had a default output for queries, the returned object seems a good fit Regards, -- dim PS: I'll go mark as returned with feedback but intend to complete this review in the following days, by having a look at the code and documentation. Unless beaten to it, as I won't be able to give accurate guidance for pursuing effort.
Dimitri Fontaine wrote: > So here are the major points about this patch: > > - it's missing the returns declaration syntax (default value could be > returns void?) > > - it would be much more friendly to users if it had a default output > for queries, the returned object seems a good fit > > > Really? That wasn't my expectation at all. I expected that the code would in effect be always returning void. I think you're moving the goalposts a bit here. I don't think we need a RETURNS clause on it for it to be useful. cheers andrew
Andrew Dunstan <andrew@dunslane.net> writes: > Dimitri Fontaine wrote: >> So here are the major points about this patch: >> - it's missing the returns declaration syntax (default value could be >> returns void?) >> - it would be much more friendly to users if it had a default output >> for queries, the returned object seems a good fit > Really? That wasn't my expectation at all. I expected that the code > would in effect be always returning void. I think you're moving the > goalposts a bit here. I don't think we need a RETURNS clause on it for > it to be useful. Yeah. The presented examples aren't tremendously convincing, as they both beg the question "why not just do a SELECT?". It's also not exactly apparent to me why redefining the behavior of SELECT in a plpgsql function would be a better thing than having RETURN do it. I think adding onto DO capabilities is something we could do later if demand warrants. I'd prefer to underdesign it for starters than to encrust it with features that might not be needed. BTW, what happens with the current patch if you try to do a RETURN? regards, tom lane
Tom Lane napsal(a): <blockquote cite="mid:14669.1253412760@sss.pgh.pa.us" type="cite"><pre wrap="">Andrew Dunstan <a class="moz-txt-link-rfc2396E"href="mailto:andrew@dunslane.net"><andrew@dunslane.net></a> writes: </pre><blockquotetype="cite"><pre wrap="">Dimitri Fontaine wrote: </pre><blockquote type="cite"><pre wrap="">So here arethe major points about this patch: - it's missing the returns declaration syntax (default value could be returns void?) - it would be much more friendly to users if it had a default output for queries, the returned object seems a good fit </pre></blockquote></blockquote><pre wrap=""> </pre><blockquote type="cite"><prewrap="">Really? That wasn't my expectation at all. I expected that the code would in effect be always returning void. I think you're moving the goalposts a bit here. I don't think we need a RETURNS clause on it for it to be useful. </pre></blockquote><pre wrap=""> I think adding onto DO capabilities is something we could do later if demand warrants. I'd prefer to underdesign it for starters than to encrust it with features that might not be needed. </pre></blockquote><br /> Right, RETURNS can be added later withoutbreaking any existing code for users so no problem there (same goes for removing the requirement of BEGIN ... ENDfor example).<br /><br /><blockquote cite="mid:14669.1253412760@sss.pgh.pa.us" type="cite"><pre wrap="">BTW, what happenswith the current patch if you try to do a RETURN? </pre></blockquote><br /> Throws same error as function definedwith RETURNS void.<br /><br /><pre class="moz-signature" cols="72">-- Regards Petr Jelinek (PJMODOS)</pre>
On Sat, Sep 19, 2009 at 8:03 PM, Dimitri Fontaine <dfontaine@hi-media.com> wrote: > PS: I'll go mark as returned with feedback but intend to complete this > review in the following days, by having a look at the code and > documentation. Unless beaten to it, as I won't be able to give accurate > guidance for pursuing effort. That doesn't seem appropriate. Returned With Feedback means that the patch is dead as far as this CommitFest goes, which isn't what you seem to be saying at all. I think this should stay Needs Review until it's had a full review, and then we can decide where it goes from there after that. ...Robert
Hi, Tom Lane <tgl@sss.pgh.pa.us> writes: > Andrew Dunstan <andrew@dunslane.net> writes: >> Really? That wasn't my expectation at all. I expected that the code >> would in effect be always returning void. I think you're moving the >> goalposts a bit here. I don't think we need a RETURNS clause on it for >> it to be useful. Yes it'd be useful without it too, and this can come in later in the game, granted too. Will continue review without it. > Yeah. The presented examples aren't tremendously convincing, as they > both beg the question "why not just do a SELECT?". Where I want to go from those example are for the first case being able to run SQL commands on a bunch of tables and return a 3 setof (schemaname, tablename, check bool). The second one (server_version) is intended to go in extension install script, in order to branch on the server_version and behave accordingly, returning what it is that have been done or sth useful. But I didn't give it much time yet, and I'll confess it was the first ideas coming in while playing with the feature. Proper ways to do things with what's currently in the patch may come after some more playing. > It's also not > exactly apparent to me why redefining the behavior of SELECT in a > plpgsql function would be a better thing than having RETURN do it. Well convenience for lazy DBA only, skipping the declaring of vars in a DO command... it's following the idea that we might want not exactly plpgsql in there, which I can see as a very bad one too, wrt code maintenance and all. Maybe offering later a new PL intended at "interactive" processing would better fit this line of thoughs. > I think adding onto DO capabilities is something we could do later > if demand warrants. I'd prefer to underdesign it for starters than > to encrust it with features that might not be needed. > > BTW, what happens with the current patch if you try to do a RETURN? dim=# do $$begin return; end;$$; ERROR: invalid typLen: 0 CONTEXT: PL/pgSQL function "inline" while casting return value to function's return type dim=# do $$begin return 1; end;$$; ERROR: RETURN cannot have a parameter in function returning void at or near "1" LINE 1: do $$begin return 1; end;$$; ^ Regards, -- Dimitri Fontaine PostgreSQL DBA, Architecte
Robert Haas <robertmhaas@gmail.com> writes: > That doesn't seem appropriate. Returned With Feedback means that the > patch is dead as far as this CommitFest goes, which isn't what you > seem to be saying at all. I think this should stay Needs Review until > it's had a full review, and then we can decide where it goes from > there after that. Yeah, don't want to close it already. Bitten by the labels once more, but it'll come :) -- Dimitri Fontaine PostgreSQL DBA, Architecte
(This is a partial review of the grantonall-20090810v2.diff patch posted by Petr Jelinek on 2009-08-10 (hi PJMODOS!). See http://archives.postgresql.org/message-id/4A7F5853.5010506@pjmodos.net for the original message.) I have not yet been able to do a complete review of this patch, but I am posting this because I'll be travelling for a week starting tomorrow. My comments are based mostly on reading the patch, and not on any intensive testing of the feature. I have left the patch status unchanged at "needs review", although I think it's close to "ready for committer". I really like this patch. It's easy to understand and written in a very straightforward way, and addresses a real need that comes up time and again on various support fora. I have only a couple of minor comments. 1. The patch did apply to HEAD and build cleanly, but there are now a couple of minor (documentation) conflicts. (Sorry,I would have fixed them and reposted a patch, but I'm running out of time right now.) > *** a/doc/src/sgml/ref/grant.sgml > --- b/doc/src/sgml/ref/grant.sgml > [...] > > <para> > + There is also the possibility of granting permissions to all objects of > + given type inside one or multiple schemas. This functionality is supported > + for tables, views, sequences and functions and can done by using > + ALL {TABLES|SEQUENCES|FUNCTIONS} IN SCHEMA schemaname syntax in place > + of object name. > + </para> > + > + <para> 2. Here I suggest the following wording: <para> You can also grant permissions on all tables, sequences, or functions that currently exist within a given schemaby specifying "ALL {TABLES|SEQUENCES|FUNCTIONS} IN SCHEMA schemaname" in place of an object name. </para> 3. I believe MySQL's "grant all privileges on foo.* to someone" grants privileges on all existing objects in foo _but also_on any objects that may be created later. This patch only gives you a way to grant privileges only on the objectscurrently within a schema. I strongly prefer this behaviour myself, but I do think the documentation needs a briefmention of this fact, to avoid surprising people. That's why I added "that currently exist" to (2), above. Maybe anothersentence that specifically says that objects created later are unaffected is in order. I'm not sure. -- ams
2009/9/20 Dimitri Fontaine <dfontaine@hi-media.com>: > Hi, > > Tom Lane <tgl@sss.pgh.pa.us> writes: >> Andrew Dunstan <andrew@dunslane.net> writes: >>> Really? That wasn't my expectation at all. I expected that the code >>> would in effect be always returning void. I think you're moving the >>> goalposts a bit here. I don't think we need a RETURNS clause on it for >>> it to be useful. > > Yes it'd be useful without it too, and this can come in later in the > game, granted too. Will continue review without it. Hello I think so RETURN there has some sense. It should be optional, and have to specify exit status. So return non zero value means exit psql with returned value as exit status. It would be interesting, if we could access from anonymous block some psql internal variables. regards Pavel Stehule
At 2009-09-20 20:20:11 +0530, ams@toroid.org wrote: > > 1. The patch did apply to HEAD and build cleanly, but there are now a > couple of minor (documentation) conflicts. To be more clear, what I meant is that it did apply and build cleanly when it was posted, but things have drifted enough now that applying it causes conflicts in some sgml files. -- ams
Abhijit Menon-Sen wrote:
I'll leave the exact wording to commiter, but in the attached patch I changed it to say "all existing objects" instead of "all objects".
Except for above two changes and the fact that it's against current head, the patch is exactly the same.
Thanks again.
Thanks for your review.I have not yet been able to do a complete review of this patch, but I am posting this because I'll be travelling for a week starting tomorrow. My comments are based mostly on reading the patch, and not on any intensive testing of the feature. I have left the patch status unchanged at "needs review", although I think it's close to "ready for committer".
I fixed those conflicts in attached patch.1. The patch did apply to HEAD and build cleanly, but there are now a couple of minor (documentation) conflicts. (Sorry, I would have fixed them and reposted a patch, but I'm running out of time right now.)
*** a/doc/src/sgml/ref/grant.sgml --- b/doc/src/sgml/ref/grant.sgml [...] <para> + There is also the possibility of granting permissions to all objects of + given type inside one or multiple schemas. This functionality is supported + for tables, views, sequences and functions and can done by using + ALL {TABLES|SEQUENCES|FUNCTIONS} IN SCHEMA schemaname syntax in place + of object name. + </para> + + <para>2. Here I suggest the following wording: <para> You can also grant permissions on all tables, sequences, or functions that currently exist within a given schema by specifying "ALL {TABLES|SEQUENCES|FUNCTIONS} IN SCHEMA schemaname" in place of an object name. </para> 3. I believe MySQL's "grant all privileges on foo.* to someone" grants privileges on all existing objects in foo _but also_ on any objects that may be created later. This patch only gives you a way to grant privileges only on the objects currently within a schema. I strongly prefer this behaviour myself, but I do think the documentation needs a brief mention of this fact, to avoid surprising people. That's why I added "that currently exist" to (2), above. Maybe another sentence that specifically says that objects created later are unaffected is in order. I'm not sure.
I'll leave the exact wording to commiter, but in the attached patch I changed it to say "all existing objects" instead of "all objects".
Except for above two changes and the fact that it's against current head, the patch is exactly the same.
Thanks again.
-- Regards Petr Jelinek (PJMODOS)
Attachment
Hi, Dimitri Fontaine <dfontaine@hi-media.com> writes: > Patch applies cleanly and build cleanly too, basic examples are working > fine. I've been reading through the code and am going to mark it as ready for commiter, as only remarks I have are probably because I do not know enough about PostgreSQL internals, and the one I missed are in the same category. The patch is easy to read and all it does looks straightforward, even for me :) Here we go: *** a/src/backend/tcop/utility.c --- b/src/backend/tcop/utility.c ... *************** UtilityReturnsTuples(Node *parsetree) *** 1147,1155 **** ... - case T_ExplainStmt: - return true; - Is this not a oversight in the final patch? + /* This is short-lived, so needn't allocate in function's cxt */ + plpgsql_Datums = palloc(sizeof(PLpgSQL_datum *) * datums_alloc); ... + compile_tmp_cxt = MemoryContextSwitchTo(func_cxt); I wonder why not having the datums into the func_cxt too. Regards, -- dim
Dimitri Fontaine napsal(a):
It is. I attached patch which does not have this part.
Actually I think we might not need that function memory context for anonymous code blocks at all since we don't cache compiled functions. But I am not sure so I basically copied it from standard function compiler to be on safe side. I am sure commiter will comment on this :)
Hi, Dimitri Fontaine <dfontaine@hi-media.com> writes:Patch applies cleanly and build cleanly too, basic examples are working fine.I've been reading through the code and am going to mark it as ready for commiter, as only remarks I have are probably because I do not know enough about PostgreSQL internals, and the one I missed are in the same category. The patch is easy to read and all it does looks straightforward, even for me :) Here we go: *** a/src/backend/tcop/utility.c --- b/src/backend/tcop/utility.c ... *************** UtilityReturnsTuples(Node *parsetree) *** 1147,1155 **** ... - case T_ExplainStmt: - return true; - Is this not a oversight in the final patch?
It is. I attached patch which does not have this part.
+ /* This is short-lived, so needn't allocate in function's cxt */ + plpgsql_Datums = palloc(sizeof(PLpgSQL_datum *) * datums_alloc); ... + compile_tmp_cxt = MemoryContextSwitchTo(func_cxt); I wonder why not having the datums into the func_cxt too.
Actually I think we might not need that function memory context for anonymous code blocks at all since we don't cache compiled functions. But I am not sure so I basically copied it from standard function compiler to be on safe side. I am sure commiter will comment on this :)
-- Regards Petr Jelinek (PJMODOS)
Attachment
Petr Jelinek <pjmodos@pjmodos.net> writes: > It is. I attached patch which does not have this part. do.sgml seems missing? regards, tom lane
On Sat, Sep 19, 2009 at 8:23 PM, Andrew Dunstan <andrew@dunslane.net> wrote: > Dimitri Fontaine wrote: >> >> So here are the major points about this patch: >> >> - it's missing the returns declaration syntax (default value could be >> returns void?) >> >> - it would be much more friendly to users if it had a default output >> for queries, the returned object seems a good fit >> > > Really? That wasn't my expectation at all. I expected that the code would in > effect be always returning void. I think you're moving the goalposts a bit > here. I don't think we need a RETURNS clause on it for it to be useful. A note about void returning functions....there are no send/recv functions for the void type which will cause problems for users of this feature over the binary protocol. You can work around this with normal functions by forcing them to return a value but not with ACB. Is there any reason why void doens't have send/recv? merlin
Merlin Moncure <mmoncure@gmail.com> writes: > A note about void returning functions....there are no send/recv > functions for the void type which will cause problems for users of > this feature over the binary protocol. This isn't a SELECT and doesn't return anything, so I don't see the issue. regards, tom lane
Tom Lane <tgl@sss.pgh.pa.us> writes: > Merlin Moncure <mmoncure@gmail.com> writes: >> A note about void returning functions....there are no send/recv >> functions for the void type which will cause problems for users of >> this feature over the binary protocol. > > This isn't a SELECT and doesn't return anything, so I don't see the > issue. I somehow had to force me into thinking about DO as a Utility command and not a query... but I guess the previous discussion about wanting to have a lambda construct and functions as types confused us. We're not there yet, DO is only a utility command. Regards, -- dim
Petr Jelinek <pjmodos@pjmodos.net> writes: > [ anonymous code blocks patch ] I committed this after some editorialization. Aside from adding missing CREATE LANGUAGE and pg_dump support, I didn't like the API for inline handler functions. Passing just a C string doesn't allow for any future expansibility (eg adding parameters), and it represents a security hole because anyone could call the function, thereby bypassing the privilege checks. I changed things so that the inline handlers are declared as taking type INTERNAL, which will prevent them from being called manually from SQL. Also, I made the actual argument be a new Node struct type. (I first thought of passing the DO statement's parse node as-is, but that would require every handler to re-implement the deconstruction of the DefElem list. So a separate struct type seemed like a better idea.) With this, we can add parameters or what have you without any changes in the catalog-level representation of the languages or inline handlers. I did some renaming too --- we generally expect that parsenodes associated with statement types are named after the statement, for instance. The do.sgml file was missing from both your submissions, so I cooked up a very quick-and-dirty reference page. It could stand to be fleshed out a bit, probably. If there's useful material in your original, please submit a followon patch to add it. > Actually I think we might not need that function memory context for > anonymous code blocks at all since we don't cache compiled functions. > But I am not sure so I basically copied it from standard function > compiler to be on safe side. I am sure commiter will comment on this :) Yeah, I got rid of that: it created a session-lifespan memory leak for every execution of a DO command. There's no reason not to just do it in the current memory context. regards, tom lane
Tom Lane napsal(a): <blockquote cite="mid:7067.1253663369@sss.pgh.pa.us" type="cite"><pre wrap="">Petr Jelinek <a class="moz-txt-link-rfc2396E"href="mailto:pjmodos@pjmodos.net"><pjmodos@pjmodos.net></a> writes: </pre><blockquotetype="cite"><pre wrap=""> [ anonymous code blocks patch ] </pre></blockquote><pre wrap=""> I committed this after some editorialization. Aside from adding missing CREATE LANGUAGE and pg_dump support, I didn't like the API for inline handler functions. Passing just a C string doesn't allow for any future expansibility (eg adding parameters), and it represents a security hole because anyone could call the function, thereby bypassing the privilege checks. I changed things so that the inline handlers are declared as taking type INTERNAL, which will prevent them from being called manually from SQL. Also, I made the actual argument be a new Node struct type. (I first thought of passing the DO statement's parse node as-is, but that would require every handler to re-implement the deconstruction of the DefElem list. So a separate struct type seemed like a better idea.) With this, we can add parameters or what have you without any changes in the catalog-level representation of the languages or inline handlers. I did some renaming too --- we generally expect that parsenodes associated with statement types are named after the statement, for instance. </pre></blockquote><br /> Good work as always, thanks.<br /><br /><blockquote cite="mid:7067.1253663369@sss.pgh.pa.us"type="cite"><pre wrap="">The do.sgml file was missing from both your submissions,so I cooked up a very quick-and-dirty reference page. It could stand to be fleshed out a bit, probably. If there's useful material in your original, please submit a followon patch to add it. </pre></blockquote><br /> Aside from worse wording in my version the only differenceis the example.<br /> I used (and I am killing GRANT ON ALL patch now):<br /> <para><br /> Grant allprivileges on all VIEWs in schema <literal>public</> to role <literal>webuser</>.<br /> <programlisting><br/> DO $$DECLARE r record;<br /> BEGIN<br /> FOR r IN SELECT table_schema, table_name FROM information_schema.tables<br/> WHERE table_type = 'VIEW' AND table_schema = 'public'<br /> LOOP<br /> EXECUTE 'GRANT ALL ON ' || quote_literal(r.table_schema) || '.' || quote_literal(r.table_name) || ' TO webuser';<br/> END LOOP;<br /> END$$;<br /> </programlisting><br /> </para><br /> <br /><br /><pre class="moz-signature"cols="72">-- Regards Petr Jelinek (PJMODOS)</pre>
Petr Jelinek <pjmodos@pjmodos.net> writes: > Tom Lane napsal(a): >> The do.sgml file was missing from both your submissions, so I cooked >> up a very quick-and-dirty reference page. It could stand to be fleshed >> out a bit, probably. If there's useful material in your original, >> please submit a followon patch to add it. > Aside from worse wording in my version the only difference is the example. > I used (and I am killing GRANT ON ALL patch now): Applied, thanks. regards, tom lane
2009/9/21 Petr Jelinek <pjmodos@pjmodos.net>: > Abhijit Menon-Sen wrote: > > I have not yet been able to do a complete review of this patch, but I am > posting this because I'll be travelling for a week starting tomorrow. My > comments are based mostly on reading the patch, and not on any intensive > testing of the feature. I have left the patch status unchanged at "needs > review", although I think it's close to "ready for committer". > > > Thanks for your review. > > 1. The patch did apply to HEAD and build cleanly, but there are now a > couple of minor (documentation) conflicts. (Sorry, I would have fixed > them and reposted a patch, but I'm running out of time right now.) > > > I fixed those conflicts in attached patch. > > > > *** a/doc/src/sgml/ref/grant.sgml > --- b/doc/src/sgml/ref/grant.sgml > [...] > > <para> > + There is also the possibility of granting permissions to all objects of > + given type inside one or multiple schemas. This functionality is > supported > + for tables, views, sequences and functions and can done by using > + ALL {TABLES|SEQUENCES|FUNCTIONS} IN SCHEMA schemaname syntax in place > + of object name. > + </para> > + > + <para> > > > 2. Here I suggest the following wording: > > <para> > You can also grant permissions on all tables, sequences, or > functions that currently exist within a given schema by specifying > "ALL {TABLES|SEQUENCES|FUNCTIONS} IN SCHEMA schemaname" in place of > an object name. > </para> > > 3. I believe MySQL's "grant all privileges on foo.* to someone" grants > privileges on all existing objects in foo _but also_ on any objects > that may be created later. This patch only gives you a way to grant > privileges only on the objects currently within a schema. I strongly > prefer this behaviour myself, but I do think the documentation needs > a brief mention of this fact, to avoid surprising people. That's why > I added "that currently exist" to (2), above. Maybe another sentence > that specifically says that objects created later are unaffected is > in order. I'm not sure. > > > I'll leave the exact wording to commiter, but in the attached patch I > changed it to say "all existing objects" instead of "all objects". > > Except for above two changes and the fact that it's against current head, > the patch is exactly the same. Abhijit, If this patch looks good now, can you mark it Ready for Committer in the CommitFest app? If there are any remaining issues, please post a further review. Thanks, ...Robert
Robert Haas napsal(a): > Abhijit, > > If this patch looks good now, can you mark it Ready for Committer in > the CommitFest app? If there are any remaining issues, please post a > further review. > I believe he'll be out for two more days. -- Regards Petr Jelinek (PJMODOS)
At 2009-09-27 12:54:48 -0400, robertmhaas@gmail.com wrote: > > If this patch looks good now, can you mark it Ready for Committer in > the CommitFest app? Done. -- ams
On Sun, Sep 27, 2009 at 11:54 AM, Robert Haas <robertmhaas@gmail.com> wrote: > > If this patch looks good now, can you mark it Ready for Committer in > the CommitFest app? If there are any remaining issues, please post a > further review. > while i'm not the reviewer this patch doesn't apply cleanly anymore... some comments: 1) in docs for REVOKE you're omitting the SCHEMA part of the new syntax. 2) i think that getNamespacesObjectsOids() could be rewritten in something like: + { + List *objects = NIL; + ListCell *cell; + char *nspname; + Oid namespaceId; + + foreach(cell, nspnames) + { + List *relations = NIL; + + nspname = strVal(lfirst(cell)); + namespaceId = LookupExplicitNamespace(nspname); + switch (objtype) + { + /* do what you need for every type of object here */ + + } i think this is more readable -- Atentamente, Jaime Casanova Soporte y capacitación de PostgreSQL Asesoría y desarrollo de sistemas Guayaquil - Ecuador Cel. +59387171157
Jaime Casanova napsal(a):
Fixed.
Fixed.
Right.
On Sun, Sep 27, 2009 at 11:54 AM, Robert Haas <robertmhaas@gmail.com> wrote:If this patch looks good now, can you mark it Ready for Committer in the CommitFest app? If there are any remaining issues, please post a further review.while i'm not the reviewer this patch doesn't apply cleanly anymore...
Fixed.
some comments: 1) in docs for REVOKE you're omitting the SCHEMA part of the new syntax.
Fixed.
2) i think that getNamespacesObjectsOids() could be rewritten in something like:
Right.
-- Regards Petr Jelinek (PJMODOS)
Attachment
Petr Jelinek <pjmodos@pjmodos.net> writes: > [ latest GRANT ALL patch ] I started looking at this, and the first thing I noticed was that it adds TABLES, FUNCTIONS, and SEQUENCES as unreserved keywords. Now I'm not a fan of bloating the parser that way, but I have to admit that "GRANT ON ALL TABLE IN SCHEMA" wouldn't read well. What I am wondering is whether we should not go back and adjust the syntax for the default-ACLs patch to use the same keywords, ie not ALTER DEFAULT PRIVILEGES ... GRANT ... ON TABLE TO ... but ALTER DEFAULT PRIVILEGES ... GRANT ... ON TABLES TO ... Comments? regards, tom lane
On Mon, Oct 12, 2009 at 1:42 PM, Tom Lane <tgl@sss.pgh.pa.us> wrote: > > ALTER DEFAULT PRIVILEGES ... GRANT ... ON TABLES TO ... > this makes sense to me, because you want the default to affect all new tables not only a new single table. so, as someone once told, +1 from me ;) -- Atentamente, Jaime Casanova Soporte y capacitación de PostgreSQL Asesoría y desarrollo de sistemas Guayaquil - Ecuador Cel. +59387171157
Petr Jelinek <pjmodos@pjmodos.net> writes: > [ GRANT ON ALL ] Applied with minor editorialization (mainly changing some choices of identifiers) regards, tom lane
Jaime Casanova <jcasanov@systemguards.com.ec> writes: > On Mon, Oct 12, 2009 at 1:42 PM, Tom Lane <tgl@sss.pgh.pa.us> wrote: >> ALTER DEFAULT PRIVILEGES ... GRANT ... ON TABLES TO ... > this makes sense to me, because you want the default to affect all new > tables not only a new single table. > so, as someone once told, +1 from me ;) Done. regards, tom lane
2009/10/13 Tom Lane <tgl@sss.pgh.pa.us>: > I started looking at this, and the first thing I noticed was that it > adds TABLES, FUNCTIONS, and SEQUENCES as unreserved keywords. Now > I'm not a fan of bloating the parser that way, but I have to admit > that "GRANT ON ALL TABLE IN SCHEMA" wouldn't read well. What I am > wondering is whether we should not go back and adjust the syntax > for the default-ACLs patch to use the same keywords, ie not > > ALTER DEFAULT PRIVILEGES ... GRANT ... ON TABLE TO ... > > but > > ALTER DEFAULT PRIVILEGES ... GRANT ... ON TABLES TO ... > > Comments? My personal feeling is that the syntax of ALTER DEFAULT PRIVILEGES works fine as it stands. When you specify a default priv of "GRANT SELECT ON TABLE TO dave" on a schema, it means that whenever you create a table it implicitly does a "GRANT SELECT ON <new table> TO dave". I think the symmetry between the default priv and the related GRANT outweighs the consideration of whether the command parses more like a valid English sentence. Cheers, BJ