Skip to content
Projects
Groups
Snippets
Help
Loading...
Help
Support
Keyboard shortcuts
?
Submit feedback
Contribute to GitLab
Sign in
Toggle navigation
P
Postgres FD Implementation
Project overview
Project overview
Details
Activity
Releases
Repository
Repository
Files
Commits
Branches
Tags
Contributors
Graph
Compare
Issues
0
Issues
0
List
Boards
Labels
Milestones
Merge Requests
0
Merge Requests
0
CI / CD
CI / CD
Pipelines
Jobs
Schedules
Analytics
Analytics
CI / CD
Repository
Value Stream
Wiki
Wiki
Snippets
Snippets
Members
Members
Collapse sidebar
Close sidebar
Activity
Graph
Create a new issue
Jobs
Commits
Issue Boards
Open sidebar
Abuhujair Javed
Postgres FD Implementation
Commits
4355d4fb
Commit
4355d4fb
authored
Jun 29, 2003
by
Peter Eisentraut
Browse files
Options
Browse Files
Download
Email Patches
Plain Diff
Information schema views for group privileges, some corrections on column
privileges.
parent
ae20518c
Changes
2
Show whitespace changes
Inline
Side-by-side
Showing
2 changed files
with
734 additions
and
43 deletions
+734
-43
doc/src/sgml/information_schema.sgml
doc/src/sgml/information_schema.sgml
+536
-17
src/backend/catalog/information_schema.sql
src/backend/catalog/information_schema.sql
+198
-26
No files found.
doc/src/sgml/information_schema.sgml
View file @
4355d4fb
<!-- $Header: /cvsroot/pgsql/doc/src/sgml/information_schema.sgml,v 1.
5 2003/06/28 20:50:07
petere Exp $ -->
<!-- $Header: /cvsroot/pgsql/doc/src/sgml/information_schema.sgml,v 1.
6 2003/06/29 15:14:41
petere Exp $ -->
<chapter id="information-schema">
<title>The Information Schema</title>
...
...
@@ -142,6 +142,52 @@
</table>
</sect1>
<sect1 id="infoschema-applicable-roles">
<title><literal>applicable_roles</literal></title>
<para>
The view <literal>applicable_roles</literal> identifies all groups
that the current user is a member of. (A role is the same thing as
a group.) Generally, it is better to use the view
<literal>enabled_roles</literal> instead of this one; see also
there.
</para>
<table>
<title><literal>applicable_roles</literal> Columns</title>
<tgroup cols="3">
<thead>
<row>
<entry>Name</entry>
<entry>Data Type</entry>
<entry>Description</entry>
</row>
</thead>
<tbody>
<row>
<entry><literal>grantee</literal></entry>
<entry><type>sql_identifier</type></entry>
<entry>Always the name of the current user</entry>
</row>
<row>
<entry><literal>role_name</literal></entry>
<entry><type>sql_identifier</type></entry>
<entry>Name of a group</entry>
</row>
<row>
<entry><literal>is_grantable</literal></entry>
<entry><type>character_data</type></entry>
<entry>Applies to a feature not available in PostgreSQL</entry>
</row>
</tbody>
</tgroup>
</table>
</sect1>
<sect1 id="infoschema-check-constraints">
<title><literal>check_constraints</literal></title>
...
...
@@ -268,7 +314,8 @@
The view <literal>column_privileges</literal> identifies all
privileges granted on columns to the current user or by the current
user. There is one row for each combination of column, grantor,
and grantee.
and grantee. Privileges granted to groups are identified in the
view <literal>role_column_grants</literal>.
</para>
<para>
...
...
@@ -276,9 +323,13 @@
individual columns. Therefore, this view contains the same
information as <literal>table_privileges</literal>, just
represented through one row for each column in each appropriate
table. But if you want to make your applications fit for possible
future developements, it is generally the right choice to use this
view instead of <literal>table_privileges</literal>.
table, but it only convers privilege types where column granularity
is possible: <literal>SELECT</literal>, <literal>INSERT</literal>,
<literal>UPDATE</literal>, <literal>REFERENCES</literal>. If you
want to make your applications fit for possible future
developements, it is generally the right choice to use this view
instead of <literal>table_privileges</literal> if one of those
privilege types is concerned.
</para>
<table>
...
...
@@ -303,7 +354,7 @@
<row>
<entry><literal>grantee</literal</entry>
<entry><type>sql_identifier</type></entry>
<entry>Name of the user that the privilege was granted to</entry>
<entry>Name of the user
or group
that the privilege was granted to</entry>
</row>
<row>
...
...
@@ -335,9 +386,8 @@
<entry><type>character_data</type></entry>
<entry>
Type of the privilege: <literal>SELECT</literal>,
<literal>DELETE</literal>, <literal>INSERT</literal>,
<literal>UPDATE</literal>, <literal>REFERENCES</literal>, or
<literal>TRIGGER</literal>
<literal>INSERT</literal>, <literal>UPDATE</literal>, or
<literal>REFERENCES</literal>
</entry>
</row>
...
...
@@ -349,6 +399,14 @@
</tbody>
</tgroup>
</table>
<para>
Note that the column <literal>grantee</literal> makes no
distinction between users and groups. If you have users and groups
with the same name, there is unfortunately no way to distinguish
them. A future version of PostgreSQL will possibly prohibit having
users and groups with the same name.
</para>
</sect1>
<sect1 id="infoschema-column-udt-usage">
...
...
@@ -1627,6 +1685,42 @@ ORDER BY c.ordinal_position;
</table>
</sect1>
<sect1 id="infoschema-enabled-roles">
<title><literal>enabled_roles</literal></title>
<para>
The view <literal>enabled_roles</literal> identifies all groups
that the current user is a member of. (A role is the same thing as
a group.) The difference between this view and
<literal>applicable_roles</literal> is that in the future there may
be a mechanism to enable and disable groups during a session. In
that case this view identifies those groups that are currently
enabled.
</para>
<table>
<title><literal>enabled_roles</literal> Columns</title>
<tgroup cols="3">
<thead>
<row>
<entry>Name</entry>
<entry>Data Type</entry>
<entry>Description</entry>
</row>
</thead>
<tbody>
<row>
<entry><literal>role_name</literal></entry>
<entry><type>sql_identifier</type></entry>
<entry>Name of a group</entry>
</row>
</tbody>
</tgroup>
</table>
</sect1>
<sect1 id="infoschema-key-column-usage">
<title><literal>key_column_usage</literal></title>
...
...
@@ -2066,6 +2160,334 @@ ORDER BY c.ordinal_position;
</table>
</sect1>
<sect1 id="infoschema-role-column-grants">
<title><literal>role_columns_grants</literal></title>
<para>
The view <literal>role_column_grants</literal> identifies all
privileges granted on columns to a group that the current user is a
member of. Further information can be found under
<literal>column_privileges</literal>.
</para>
<table>
<title><literal>role_column_grants</literal> Columns</title>
<tgroup cols="3">
<thead>
<row>
<entry>Name</entry>
<entry>Data Type</entry>
<entry>Description</entry>
</row>
</thead>
<tbody>
<row>
<entry><literal>grantor</literal></entry>
<entry><type>sql_identifier</type></entry>
<entry>Name of the user that granted the privilege</entry>
</row>
<row>
<entry><literal>grantee</literal</entry>
<entry><type>sql_identifier</type></entry>
<entry>Name of the group that the privilege was granted to</entry>
</row>
<row>
<entry><literal>table_catalog</literal></entry>
<entry><type>sql_identifier</type></entry>
<entry>Name of the database that contains the table that contains the column (always the current database)</entry>
</row>
<row>
<entry><literal>table_schema</literal</entry>
<entry><type>sql_identifier</type></entry>
<entry>Name of the schema that contains the table that contains the column</entry>
</row>
<row>
<entry><literal>table_name</literal</entry>
<entry><type>sql_identifier</type></entry>
<entry>Name of the table that contains the column</entry>
</row>
<row>
<entry><literal>column_name</literal</entry>
<entry><type>sql_identifier</type></entry>
<entry>Name of the column</entry>
</row>
<row>
<entry><literal>privilege_type</literal</entry>
<entry><type>character_data</type></entry>
<entry>
Type of the privilege: <literal>SELECT</literal>,
<literal>INSERT</literal>, <literal>UPDATE</literal>, or
<literal>REFERENCES</literal>
</entry>
</row>
<row>
<entry><literal>is_grantable</literal></entry>
<entry><type>character_data</type></entry>
<entry><literal>YES</literal> if the privilege is grantable, <literal>NO</literal> if not</entry>
</row>
</tbody>
</tgroup>
</table>
</sect1>
<sect1 id="infoschema-role-routine-grants">
<title><literal>role_routine_grants</literal></title>
<para>
The view <literal>role_routine_grants</literal> identifies all
privileges granted on functions to a group that the current user is
a member of. Further information can be found under
<literal>routine_privileges</literal>.
</para>
<table>
<title><literal>role_routine_grants</literal> Columns</title>
<tgroup cols="3">
<thead>
<row>
<entry>Name</entry>
<entry>Data Type</entry>
<entry>Description</entry>
</row>
</thead>
<tbody>
<row>
<entry><literal>grantor</literal></entry>
<entry><type>sql_identifier</type></entry>
<entry>Name of the user that granted the privilege</entry>
</row>
<row>
<entry><literal>grantee</literal</entry>
<entry><type>sql_identifier</type></entry>
<entry>Name of the group that the privilege was granted to</entry>
</row>
<row>
<entry><literal>specific_catalog</literal></entry>
<entry><type>sql_identifier</type></entry>
<entry>Name of the database containing the function (always the current database)</entry>
</row>
<row>
<entry><literal>specific_schema</literal></entry>
<entry><type>sql_identifier</type></entry>
<entry>Name of the schema containing the function</entry>
</row>
<row>
<entry><literal>specific_name</literal></entry>
<entry><type>sql_identifier</type></entry>
<entry>
The <quote>specific name</quote> of the function. See <xref
linkend="infoschema-routines"> for more information.
</entry>
</row>
<row>
<entry><literal>routine_catalog</literal></entry>
<entry><type>sql_identifier</type></entry>
<entry>Name of the database containing the function (always the current database)</entry>
</row>
<row>
<entry><literal>routine_schema</literal></entry>
<entry><type>sql_identifier</type></entry>
<entry>Name of the schema containing the function</entry>
</row>
<row>
<entry><literal>routine_name</literal></entry>
<entry><type>sql_identifier</type></entry>
<entry>Name of the function (may be duplicated in case of overloading)</entry>
</row>
<row>
<entry><literal>privilege_type</literal</entry>
<entry><type>character_data</type></entry>
<entry>Always <literal>EXECUTE</literal> (the only privilege type for functions)</entry>
</row>
<row>
<entry><literal>is_grantable</literal></entry>
<entry><type>character_data</type></entry>
<entry><literal>YES</literal> if the privilege is grantable, <literal>NO</literal> if not</entry>
</row>
</tbody>
</tgroup>
</table>
</sect1>
<sect1 id="infoschema-role-table-grants">
<title><literal>role_table_grants</literal></title>
<para>
The view <literal>role_table_grants</literal> identifies all
privileges granted on tables or views to a group that the current
user is a member of. Further information can be found under
<literal>table_privileges</literal>.
</para>
<table>
<title><literal>role_table_grants</literal> Columns</title>
<tgroup cols="3">
<thead>
<row>
<entry>Name</entry>
<entry>Data Type</entry>
<entry>Description</entry>
</row>
</thead>
<tbody>
<row>
<entry><literal>grantor</literal></entry>
<entry><type>sql_identifier</type></entry>
<entry>Name of the user that granted the privilege</entry>
</row>
<row>
<entry><literal>grantee</literal</entry>
<entry><type>sql_identifier</type></entry>
<entry>Name of the group that the privilege was granted to</entry>
</row>
<row>
<entry><literal>table_catalog</literal></entry>
<entry><type>sql_identifier</type></entry>
<entry>Name of the database that contains the table (always the current database)</entry>
</row>
<row>
<entry><literal>table_schema</literal</entry>
<entry><type>sql_identifier</type></entry>
<entry>Name of the schema that contains the table</entry>
</row>
<row>
<entry><literal>table_name</literal</entry>
<entry><type>sql_identifier</type></entry>
<entry>Name of the table</entry>
</row>
<row>
<entry><literal>privilege_type</literal</entry>
<entry><type>character_data</type></entry>
<entry>
Type of the privilege: <literal>SELECT</literal>,
<literal>DELETE</literal>, <literal>INSERT</literal>,
<literal>UPDATE</literal>, <literal>REFERENCES</literal>,
<literal>RULE</literal>, or <literal>TRIGGER</literal>
</entry>
</row>
<row>
<entry><literal>is_grantable</literal></entry>
<entry><type>character_data</type></entry>
<entry><literal>YES</literal> if the privilege is grantable, <literal>NO</literal> if not</entry>
</row>
<row>
<entry><literal>with_hierarchy</literal></entry>
<entry><type>character_data</type></entry>
<entry>Applies to a feature not available in PostgreSQL</entry>
</row>
</tbody>
</tgroup>
</table>
</sect1>
<sect1 id="infoschema-role-usage-grants">
<title><literal>role_usage_grants</literal></title>
<para>
The view <literal>role_usage_grants</literal> is meant to identify
<literal>USAGE</literal> privileges granted on various kinds of
objects to a group that the current user is a member of. In
PostgreSQL, this currently only applies to domains, and since
domains do not have real privileges in PostgreSQL, this view is
empty. Futher information can be found under
<literal>usage_privileges</literal>. In the future, this view may
contain more useful information.
</para>
<table>
<title><literal>role_usage_grants</literal> Columns</title>
<tgroup cols="3">
<thead>
<row>
<entry>Name</entry>
<entry>Data Type</entry>
<entry>Description</entry>
</row>
</thead>
<tbody>
<row>
<entry><literal>grantor</literal></entry>
<entry><type>sql_identifier</type></entry>
<entry>In the future, the name of the user that granted the privilege</entry>
</row>
<row>
<entry><literal>grantee</literal</entry>
<entry><type>sql_identifier</type></entry>
<entry>In the future, the name of the group that the privilege was granted to</entry>
</row>
<row>
<entry><literal>object_catalog</literal></entry>
<entry><type>sql_identifier</type></entry>
<entry>Name of the database containing the object (always the current database)</entry>
</row>
<row>
<entry><literal>object_schema</literal></entry>
<entry><type>sql_identifier</type></entry>
<entry>Name of the schema containing the object</entry>
</row>
<row>
<entry><literal>object_name</literal></entry>
<entry><type>sql_identifier</type></entry>
<entry>Name of the object</entry>
</row>
<row>
<entry><literal>object_type</literal></entry>
<entry><type>character_data</type></entry>
<entry>In the future, the type of the object</entry>
</row>
<row>
<entry><literal>privilege_type</literal</entry>
<entry><type>character_data</type></entry>
<entry>Always <literal>USAGE</literal></entry>
</row>
<row>
<entry><literal>is_grantable</literal></entry>
<entry><type>character_data</type></entry>
<entry><literal>YES</literal> if the privilege is grantable, <literal>NO</literal> if not</entry>
</row>
</tbody>
</tgroup>
</table>
</sect1>
<sect1 id="infoschema-routine-privileges">
<title><literal>routine_privileges</literal></title>
...
...
@@ -2073,7 +2495,8 @@ ORDER BY c.ordinal_position;
The view <literal>routine_privileges</literal> identifies all
privileges granted on functions to the current user or by the
current user. There is one row for each combination of function,
grantor, and grantee.
grantor, and grantee. Privileges granted to groups are identified
in the view <literal>role_routine_grants</literal>.
</para>
<table>
...
...
@@ -2098,7 +2521,7 @@ ORDER BY c.ordinal_position;
<row>
<entry><literal>grantee</literal</entry>
<entry><type>sql_identifier</type></entry>
<entry>Name of the user that the privilege was granted to</entry>
<entry>Name of the user
or group
that the privilege was granted to</entry>
</row>
<row>
...
...
@@ -2154,6 +2577,14 @@ ORDER BY c.ordinal_position;
</tbody>
</tgroup>
</table>
<para>
Note that the column <literal>grantee</literal> makes no
distinction between users and groups. If you have users and groups
with the same name, there is unfortunately no way to distinguish
them. A future version of PostgreSQL will possibly prohibit having
users and groups with the same name.
</para>
</sect1>
<sect1 id="infoschema-routines">
...
...
@@ -3147,9 +3578,10 @@ ORDER BY c.ordinal_position;
<para>
The view <literal>table_privileges</literal> identifies all
privileges granted on tables to the current user or by the current
user. There is one row for each combination of table, grantor, and
grantee.
privileges granted on tables or views to the current user or by the
current user. There is one row for each combination of table,
grantor, and grantee. Privileges granted to groups are identified
in the view <literal>role_table_grants</literal>.
</para>
<table>
...
...
@@ -3174,7 +3606,7 @@ ORDER BY c.ordinal_position;
<row>
<entry><literal>grantee</literal</entry>
<entry><type>sql_identifier</type></entry>
<entry>Name of the user that the privilege was granted to</entry>
<entry>Name of the user
or group
that the privilege was granted to</entry>
</row>
<row>
...
...
@@ -3201,8 +3633,8 @@ ORDER BY c.ordinal_position;
<entry>
Type of the privilege: <literal>SELECT</literal>,
<literal>DELETE</literal>, <literal>INSERT</literal>,
<literal>UPDATE</literal>, <literal>REFERENCES</literal>,
or
<literal>TRIGGER</literal>
<literal>UPDATE</literal>, <literal>REFERENCES</literal>,
<literal>
RULE</literal>, or <literal>
TRIGGER</literal>
</entry>
</row>
...
...
@@ -3220,6 +3652,14 @@ ORDER BY c.ordinal_position;
</tbody>
</tgroup>
</table>
<para>
Note that the column <literal>grantee</literal> makes no
distinction between users and groups. If you have users and groups
with the same name, there is unfortunately no way to distinguish
them. A future version of PostgreSQL will possibly prohibit having
users and groups with the same name.
</para>
</sect1>
<sect1 id="infoschema-tables">
...
...
@@ -3459,6 +3899,85 @@ ORDER BY c.ordinal_position;
</para>
</sect1>
<sect1 id="infoschema-usage-privileges">
<title><literal>usage_privileges</literal></title>
<para>
The view <literal>usage_privileges</literal> is meant to identify
<literal>USAGE</literal> privileges granted on various kinds of
objects to the current user or by the current user. In PostgreSQL,
this currently only applies to domains, and since domains do not
have real privileges in PostgreSQL, this view shows implicit
<literal>USAGE</literal> privileges granted to
<literal>PUBLIC</literal> for all domains. In the future, this
view may contain more useful information.
</para>
<table>
<title><literal>usage_privileges</literal> Columns</title>
<tgroup cols="3">
<thead>
<row>
<entry>Name</entry>
<entry>Data Type</entry>
<entry>Description</entry>
</row>
</thead>
<tbody>
<row>
<entry><literal>grantor</literal></entry>
<entry><type>sql_identifier</type></entry>
<entry>Currently set to the name of the owner of the object</entry>
</row>
<row>
<entry><literal>grantee</literal</entry>
<entry><type>sql_identifier</type></entry>
<entry>Currently always <literal>PUBLIC</literal></entry>
</row>
<row>
<entry><literal>object_catalog</literal></entry>
<entry><type>sql_identifier</type></entry>
<entry>Name of the database containing the object (always the current database)</entry>
</row>
<row>
<entry><literal>object_schema</literal></entry>
<entry><type>sql_identifier</type></entry>
<entry>Name of the schema containing the object</entry>
</row>
<row>
<entry><literal>object_name</literal></entry>
<entry><type>sql_identifier</type></entry>
<entry>Name of the object</entry>
</row>
<row>
<entry><literal>object_type</literal></entry>
<entry><type>character_data</type></entry>
<entry>Currently always <literal>DOMAIN</literal></entry>
</row>
<row>
<entry><literal>privilege_type</literal</entry>
<entry><type>character_data</type></entry>
<entry>Always <literal>USAGE</literal></entry>
</row>
<row>
<entry><literal>is_grantable</literal></entry>
<entry><type>character_data</type></entry>
<entry>Currently always <literal>NO</literal></entry>
</row>
</tbody>
</tgroup>
</table>
</sect1>
<sect1 id="infoschema-view-column-usage">
<title><literal>view_column_usage</literal></title>
...
...
src/backend/catalog/information_schema.sql
View file @
4355d4fb
...
...
@@ -4,7 +4,7 @@
*
* Copyright 2003, PostgreSQL Global Development Group
*
* $Id: information_schema.sql,v 1.1
1 2003/06/29 10:18:26
petere Exp $
* $Id: information_schema.sql,v 1.1
2 2003/06/29 15:14:41
petere Exp $
*/
/*
...
...
@@ -75,6 +75,24 @@ CREATE DOMAIN time_stamp AS timestamp(2)
DEFAULT
current_timestamp
(
2
);
/*
* 20.9
* APPLICABLE_ROLES view
*/
CREATE
VIEW
applicable_roles
AS
SELECT
CAST
(
current_user
AS
sql_identifier
)
AS
grantee
,
CAST
(
g
.
groname
AS
sql_identifier
)
AS
role_name
,
CAST
(
'NO'
AS
character_data
)
AS
is_grantable
FROM
pg_group
g
,
pg_user
u
WHERE
u
.
usesysid
=
ANY
(
g
.
grolist
)
AND
u
.
usename
=
current_user
;
GRANT
SELECT
ON
applicable_roles
TO
PUBLIC
;
/*
* 20.13
* CHECK_CONSTRAINTS view
...
...
@@ -137,7 +155,7 @@ GRANT SELECT ON column_domain_usage TO PUBLIC;
CREATE
VIEW
column_privileges
AS
SELECT
CAST
(
u_grantor
.
usename
AS
sql_identifier
)
AS
grantor
,
CAST
(
u_grantee
.
use
name
AS
sql_identifier
)
AS
grantee
,
CAST
(
grantee
.
name
AS
sql_identifier
)
AS
grantee
,
CAST
(
current_database
()
AS
sql_identifier
)
AS
table_catalog
,
CAST
(
nc
.
nspname
AS
sql_identifier
)
AS
table_schema
,
CAST
(
c
.
relname
AS
sql_identifier
)
AS
table_name
,
...
...
@@ -145,16 +163,21 @@ CREATE VIEW column_privileges AS
CAST
(
pr
.
type
AS
character_data
)
AS
privilege_type
,
CAST
(
CASE
WHEN
aclcontains
(
c
.
relacl
,
makeaclitem
(
u_grantee
.
usesysid
,
0
,
u_grantor
.
usesysid
,
pr
.
type
,
true
))
makeaclitem
(
grantee
.
usesysid
,
grantee
.
grosysid
,
u_grantor
.
usesysid
,
pr
.
type
,
true
))
THEN
'YES'
ELSE
'NO'
END
AS
character_data
)
AS
is_grantable
FROM
pg_attribute
a
,
pg_class
c
,
pg_namespace
nc
,
pg_user
u_grantor
,
(
SELECT
usesysid
,
usename
FROM
pg_user
UNION
SELECT
0
,
'PUBLIC'
)
AS
u_grantee
,
(
SELECT
'SELECT'
UNION
SELECT
'DELETE'
UNION
SELECT
'INSERT'
UNION
SELECT
'UPDATE'
UNION
SELECT
'REFERENCES'
UNION
SELECT
'TRIGGER'
)
AS
pr
(
type
)
(
SELECT
usesysid
,
0
,
usename
FROM
pg_user
UNION
SELECT
0
,
grosysid
,
groname
FROM
pg_group
UNION
SELECT
0
,
0
,
'PUBLIC'
)
AS
grantee
(
usesysid
,
grosysid
,
name
),
(
SELECT
'SELECT'
UNION
SELECT
'INSERT'
UNION
SELECT
'UPDATE'
UNION
SELECT
'REFERENCES'
)
AS
pr
(
type
)
WHERE
a
.
attrelid
=
c
.
oid
AND
c
.
relnamespace
=
nc
.
oid
...
...
@@ -162,10 +185,10 @@ CREATE VIEW column_privileges AS
AND
NOT
a
.
attisdropped
AND
c
.
relkind
IN
(
'r'
,
'v'
)
AND
aclcontains
(
c
.
relacl
,
makeaclitem
(
u_grantee
.
usesysid
,
0
,
u_grantor
.
usesysid
,
pr
.
type
,
false
))
makeaclitem
(
grantee
.
usesysid
,
grantee
.
grosysid
,
u_grantor
.
usesysid
,
pr
.
type
,
false
))
AND
(
u_grantor
.
usename
=
current_user
OR
u_grantee
.
use
name
=
current_user
OR
u_grantee
.
use
name
=
'PUBLIC'
);
OR
grantee
.
name
=
current_user
OR
grantee
.
name
=
'PUBLIC'
);
GRANT
SELECT
ON
column_privileges
TO
PUBLIC
;
...
...
@@ -355,10 +378,7 @@ CREATE VIEW columns AS
OR
has_table_privilege
(
c
.
oid
,
'SELECT'
)
OR
has_table_privilege
(
c
.
oid
,
'INSERT'
)
OR
has_table_privilege
(
c
.
oid
,
'UPDATE'
)
OR
has_table_privilege
(
c
.
oid
,
'DELETE'
)
OR
has_table_privilege
(
c
.
oid
,
'RULE'
)
OR
has_table_privilege
(
c
.
oid
,
'RERERENCES'
)
OR
has_table_privilege
(
c
.
oid
,
'TRIGGER'
)
);
OR
has_table_privilege
(
c
.
oid
,
'RERERENCES'
)
);
GRANT
SELECT
ON
columns
TO
PUBLIC
;
...
...
@@ -609,6 +629,20 @@ GRANT SELECT ON domains TO PUBLIC;
-- 20.27 ELEMENT_TYPES view appears later.
/*
* 20.28
* ENABLED_ROLES view
*/
CREATE
VIEW
enabled_roles
AS
SELECT
CAST
(
g
.
groname
AS
sql_identifier
)
AS
role_name
FROM
pg_group
g
,
pg_user
u
WHERE
u
.
usesysid
=
ANY
(
g
.
grolist
)
AND
u
.
usename
=
current_user
;
GRANT
SELECT
ON
enabled_roles
TO
PUBLIC
;
/*
* 20.30
* KEY_COLUMN_USAGE view
...
...
@@ -761,6 +795,132 @@ CREATE VIEW referential_constraints AS
GRANT
SELECT
ON
referential_constraints
TO
PUBLIC
;
/*
* 20.36
* ROLE_COLUMN_GRANTS view
*/
CREATE
VIEW
role_column_grants
AS
SELECT
CAST
(
u_grantor
.
usename
AS
sql_identifier
)
AS
grantor
,
CAST
(
g_grantee
.
groname
AS
sql_identifier
)
AS
grantee
,
CAST
(
current_database
()
AS
sql_identifier
)
AS
table_catalog
,
CAST
(
nc
.
nspname
AS
sql_identifier
)
AS
table_schema
,
CAST
(
c
.
relname
AS
sql_identifier
)
AS
table_name
,
CAST
(
a
.
attname
AS
sql_identifier
)
AS
column_name
,
CAST
(
pr
.
type
AS
character_data
)
AS
privilege_type
,
CAST
(
CASE
WHEN
aclcontains
(
c
.
relacl
,
makeaclitem
(
0
,
g_grantee
.
grosysid
,
u_grantor
.
usesysid
,
pr
.
type
,
true
))
THEN
'YES'
ELSE
'NO'
END
AS
character_data
)
AS
is_grantable
FROM
pg_attribute
a
,
pg_class
c
,
pg_namespace
nc
,
pg_user
u_grantor
,
pg_group
g_grantee
,
(
SELECT
'SELECT'
UNION
SELECT
'INSERT'
UNION
SELECT
'UPDATE'
UNION
SELECT
'REFERENCES'
)
AS
pr
(
type
)
WHERE
a
.
attrelid
=
c
.
oid
AND
c
.
relnamespace
=
nc
.
oid
AND
a
.
attnum
>
0
AND
NOT
a
.
attisdropped
AND
c
.
relkind
IN
(
'r'
,
'v'
)
AND
aclcontains
(
c
.
relacl
,
makeaclitem
(
0
,
g_grantee
.
grosysid
,
u_grantor
.
usesysid
,
pr
.
type
,
false
))
AND
g_grantee
.
groname
IN
(
SELECT
role_name
FROM
enabled_roles
);
GRANT
SELECT
ON
role_column_grants
TO
PUBLIC
;
/*
* 20.37
* ROLE_ROUTINE_GRANTS view
*/
CREATE
VIEW
role_routine_grants
AS
SELECT
CAST
(
u_grantor
.
usename
AS
sql_identifier
)
AS
grantor
,
CAST
(
g_grantee
.
groname
AS
sql_identifier
)
AS
grantee
,
CAST
(
current_database
()
AS
sql_identifier
)
AS
specific_catalog
,
CAST
(
n
.
nspname
AS
sql_identifier
)
AS
specific_schema
,
CAST
(
p
.
proname
||
'_'
||
CAST
(
p
.
oid
AS
text
)
AS
sql_identifier
)
AS
specific_name
,
CAST
(
current_database
()
AS
sql_identifier
)
AS
routine_catalog
,
CAST
(
n
.
nspname
AS
sql_identifier
)
AS
routine_schema
,
CAST
(
p
.
proname
AS
sql_identifier
)
AS
routine_name
,
CAST
(
'EXECUTE'
AS
character_data
)
AS
privilege_type
,
CAST
(
CASE
WHEN
aclcontains
(
p
.
proacl
,
makeaclitem
(
0
,
g_grantee
.
grosysid
,
u_grantor
.
usesysid
,
'EXECUTE'
,
true
))
THEN
'YES'
ELSE
'NO'
END
AS
character_data
)
AS
is_grantable
FROM
pg_proc
p
,
pg_namespace
n
,
pg_user
u_grantor
,
pg_group
g_grantee
WHERE
p
.
pronamespace
=
n
.
oid
AND
aclcontains
(
p
.
proacl
,
makeaclitem
(
0
,
g_grantee
.
grosysid
,
u_grantor
.
usesysid
,
'EXECUTE'
,
false
))
AND
g_grantee
.
groname
IN
(
SELECT
role_name
FROM
enabled_roles
);
GRANT
SELECT
ON
role_routine_grants
TO
PUBLIC
;
/*
* 20.38
* ROLE_TABLE_GRANTS view
*/
CREATE
VIEW
role_table_grants
AS
SELECT
CAST
(
u_grantor
.
usename
AS
sql_identifier
)
AS
grantor
,
CAST
(
g_grantee
.
groname
AS
sql_identifier
)
AS
grantee
,
CAST
(
current_database
()
AS
sql_identifier
)
AS
table_catalog
,
CAST
(
nc
.
nspname
AS
sql_identifier
)
AS
table_schema
,
CAST
(
c
.
relname
AS
sql_identifier
)
AS
table_name
,
CAST
(
pr
.
type
AS
character_data
)
AS
privilege_type
,
CAST
(
CASE
WHEN
aclcontains
(
c
.
relacl
,
makeaclitem
(
0
,
g_grantee
.
grosysid
,
u_grantor
.
usesysid
,
pr
.
type
,
true
))
THEN
'YES'
ELSE
'NO'
END
AS
character_data
)
AS
is_grantable
,
CAST
(
'NO'
AS
character_data
)
AS
with_hierarchy
FROM
pg_class
c
,
pg_namespace
nc
,
pg_user
u_grantor
,
pg_group
g_grantee
,
(
SELECT
'SELECT'
UNION
SELECT
'DELETE'
UNION
SELECT
'INSERT'
UNION
SELECT
'UPDATE'
UNION
SELECT
'REFERENCES'
UNION
SELECT
'RULE'
UNION
SELECT
'TRIGGER'
)
AS
pr
(
type
)
WHERE
c
.
relnamespace
=
nc
.
oid
AND
c
.
relkind
IN
(
'r'
,
'v'
)
AND
aclcontains
(
c
.
relacl
,
makeaclitem
(
0
,
g_grantee
.
grosysid
,
u_grantor
.
usesysid
,
pr
.
type
,
false
))
AND
g_grantee
.
groname
IN
(
SELECT
role_name
FROM
enabled_roles
);
GRANT
SELECT
ON
role_table_grants
TO
PUBLIC
;
/*
* 20.40
* ROLE_USAGE_GRANTS view
*/
-- See USAGE_PRIVILEGES.
CREATE
VIEW
role_usage_grants
AS
SELECT
CAST
(
null
AS
sql_identifier
)
AS
grantor
,
CAST
(
null
AS
sql_identifier
)
AS
grantee
,
CAST
(
current_database
()
AS
sql_identifier
)
AS
object_catalog
,
CAST
(
null
AS
sql_identifier
)
AS
object_schema
,
CAST
(
null
AS
sql_identifier
)
AS
object_name
,
CAST
(
null
AS
character_data
)
AS
object_type
,
CAST
(
'USAGE'
AS
character_data
)
AS
privilege_type
,
CAST
(
null
AS
character_data
)
AS
is_grantable
WHERE
false
;
GRANT
SELECT
ON
role_usage_grants
TO
PUBLIC
;
/*
* 20.43
* ROUTINE_PRIVILEGES view
...
...
@@ -768,7 +928,7 @@ GRANT SELECT ON referential_constraints TO PUBLIC;
CREATE
VIEW
routine_privileges
AS
SELECT
CAST
(
u_grantor
.
usename
AS
sql_identifier
)
AS
grantor
,
CAST
(
u_grantee
.
use
name
AS
sql_identifier
)
AS
grantee
,
CAST
(
grantee
.
name
AS
sql_identifier
)
AS
grantee
,
CAST
(
current_database
()
AS
sql_identifier
)
AS
specific_catalog
,
CAST
(
n
.
nspname
AS
sql_identifier
)
AS
specific_schema
,
CAST
(
p
.
proname
||
'_'
||
CAST
(
p
.
oid
AS
text
)
AS
sql_identifier
)
AS
specific_name
,
...
...
@@ -778,20 +938,26 @@ CREATE VIEW routine_privileges AS
CAST
(
'EXECUTE'
AS
character_data
)
AS
privilege_type
,
CAST
(
CASE
WHEN
aclcontains
(
p
.
proacl
,
makeaclitem
(
u_grantee
.
usesysid
,
0
,
u_grantor
.
usesysid
,
'EXECUTE'
,
true
))
makeaclitem
(
grantee
.
usesysid
,
grantee
.
grosysid
,
u_grantor
.
usesysid
,
'EXECUTE'
,
true
))
THEN
'YES'
ELSE
'NO'
END
AS
character_data
)
AS
is_grantable
FROM
pg_proc
p
,
pg_namespace
n
,
pg_user
u_grantor
,
(
SELECT
usesysid
,
usename
FROM
pg_user
UNION
SELECT
0
,
'PUBLIC'
)
AS
u_grantee
(
SELECT
usesysid
,
0
,
usename
FROM
pg_user
UNION
SELECT
0
,
grosysid
,
groname
FROM
pg_group
UNION
SELECT
0
,
0
,
'PUBLIC'
)
AS
grantee
(
usesysid
,
grosysid
,
name
)
WHERE
p
.
pronamespace
=
n
.
oid
AND
aclcontains
(
p
.
proacl
,
makeaclitem
(
u_grantee
.
usesysid
,
0
,
u_grantor
.
usesysid
,
'EXECUTE'
,
false
))
makeaclitem
(
grantee
.
usesysid
,
grantee
.
grosysid
,
u_grantor
.
usesysid
,
'EXECUTE'
,
false
))
AND
(
u_grantor
.
usename
=
current_user
OR
u_grantee
.
use
name
=
current_user
OR
u_grantee
.
use
name
=
'PUBLIC'
);
OR
grantee
.
name
=
current_user
OR
grantee
.
name
=
'PUBLIC'
);
GRANT
SELECT
ON
routine_privileges
TO
PUBLIC
;
...
...
@@ -1110,31 +1276,37 @@ GRANT SELECT ON table_constraints TO PUBLIC;
CREATE
VIEW
table_privileges
AS
SELECT
CAST
(
u_grantor
.
usename
AS
sql_identifier
)
AS
grantor
,
CAST
(
u_grantee
.
use
name
AS
sql_identifier
)
AS
grantee
,
CAST
(
grantee
.
name
AS
sql_identifier
)
AS
grantee
,
CAST
(
current_database
()
AS
sql_identifier
)
AS
table_catalog
,
CAST
(
nc
.
nspname
AS
sql_identifier
)
AS
table_schema
,
CAST
(
c
.
relname
AS
sql_identifier
)
AS
table_name
,
CAST
(
pr
.
type
AS
character_data
)
AS
privilege_type
,
CAST
(
CASE
WHEN
aclcontains
(
c
.
relacl
,
makeaclitem
(
u_grantee
.
usesysid
,
0
,
u_grantor
.
usesysid
,
pr
.
type
,
true
))
makeaclitem
(
grantee
.
usesysid
,
grantee
.
grosysid
,
u_grantor
.
usesysid
,
pr
.
type
,
true
))
THEN
'YES'
ELSE
'NO'
END
AS
character_data
)
AS
is_grantable
,
CAST
(
'NO'
AS
character_data
)
AS
with_hierarchy
FROM
pg_class
c
,
pg_namespace
nc
,
pg_user
u_grantor
,
(
SELECT
usesysid
,
usename
FROM
pg_user
UNION
SELECT
0
,
'PUBLIC'
)
AS
u_grantee
,
(
SELECT
usesysid
,
0
,
usename
FROM
pg_user
UNION
SELECT
0
,
grosysid
,
groname
FROM
pg_group
UNION
SELECT
0
,
0
,
'PUBLIC'
)
AS
grantee
(
usesysid
,
grosysid
,
name
),
(
SELECT
'SELECT'
UNION
SELECT
'DELETE'
UNION
SELECT
'INSERT'
UNION
SELECT
'UPDATE'
UNION
SELECT
'REFERENCES'
UNION
SELECT
'TRIGGER'
)
AS
pr
(
type
)
UNION
SELECT
'REFERENCES'
UNION
SELECT
'
RULE'
UNION
SELECT
'
TRIGGER'
)
AS
pr
(
type
)
WHERE
c
.
relnamespace
=
nc
.
oid
AND
c
.
relkind
IN
(
'r'
,
'v'
)
AND
aclcontains
(
c
.
relacl
,
makeaclitem
(
u_grantee
.
usesysid
,
0
,
u_grantor
.
usesysid
,
pr
.
type
,
false
))
makeaclitem
(
grantee
.
usesysid
,
grantee
.
grosysid
,
u_grantor
.
usesysid
,
pr
.
type
,
false
))
AND
(
u_grantor
.
usename
=
current_user
OR
u_grantee
.
use
name
=
current_user
OR
u_grantee
.
use
name
=
'PUBLIC'
);
OR
grantee
.
name
=
current_user
OR
grantee
.
name
=
'PUBLIC'
);
GRANT
SELECT
ON
table_privileges
TO
PUBLIC
;
...
...
Write
Preview
Markdown
is supported
0%
Try again
or
attach a new file
Attach a file
Cancel
You are about to add
0
people
to the discussion. Proceed with caution.
Finish editing this message first!
Cancel
Please
register
or
sign in
to comment