More information schema views.

This commit is contained in:
Peter Eisentraut 2003-06-17 18:00:48 +00:00
parent 3d6fd2557c
commit 596652d6eb
2 changed files with 1041 additions and 29 deletions

View File

@ -1,4 +1,4 @@
<!-- $Header: /cvsroot/pgsql/doc/src/sgml/information_schema.sgml,v 1.3 2003/06/05 16:08:47 petere Exp $ -->
<!-- $Header: /cvsroot/pgsql/doc/src/sgml/information_schema.sgml,v 1.4 2003/06/17 18:00:48 petere Exp $ -->
<chapter id="information-schema">
<title>The Information Schema</title>
@ -261,6 +261,176 @@
</table>
</sect1>
<sect1 id="infoschema-column-privileges">
<title><literal>column_privileges</literal></title>
<para>
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.
</para>
<para>
In PostgreSQL, you can only grant privileges on entire tables, not
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>.
</para>
<table>
<title><literal>column_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>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 user 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>DELETE</literal>, <literal>INSERT</literal>,
<literal>UPDATE</literal>, <literal>REFERENCES</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>
</tbody>
</tgroup>
</table>
</sect1>
<sect1 id="infoschema-column-udt-usage">
<title><literal>column_udt_usage</literal></title>
<para>
The view <literal>column_udt_usage</literal> identifies all columns
that use data types owned by the current user. Note that in
PostgreSQL, built-in data types behave like user-defined types, so
they are included here as well. See also <xref
linkend="infoschema-columns"> for details.
</para>
<table>
<title><literal>column_udt_usage</literal> Columns</title>
<tgroup cols="3">
<thead>
<row>
<entry>Name</entry>
<entry>Data Type</entry>
<entry>Description</entry>
</row>
</thead>
<tbody>
<row>
<entry><literal>udt_catalog</literal></entry>
<entry><type>sql_identifier</type></entry>
<entry>
Name of the database that the column data type (the underlying
type of the domain, if applicable) is defined in (always the
current database)
</entry>
</row>
<row>
<entry><literal>udt_schema</literal></entry>
<entry><type>sql_identifier</type></entry>
<entry>
Name of the schema that the column data type (the underlying
type of the domain, if applicable) is defined in
</entry>
</row>
<row>
<entry><literal>udt_name</literal></entry>
<entry><type>sql_identifier</type></entry>
<entry>
Name of the column data type (the underlying type of the
domain, if applicable)
</entry>
</row>
<row>
<entry><literal>table_catalog</literal></entry>
<entry><type>sql_identifier</type></entry>
<entry>Name of the database containing 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 containing 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>column_name</literal></entry>
<entry><type>sql_identifier</type></entry>
<entry>Name of the column</entry>
</row>
</tbody>
</tgroup>
</table>
</sect1>
<sect1 id="infoschema-columns">
<title><literal>columns</literal></title>
@ -595,6 +765,91 @@
</para>
</sect1>
<sect1 id="infoschema-constraint-column-usage">
<title><literal>constraint_column_usage</literal></title>
<para>
The view <literal>constraint_column_usage</literal> identifies all
columns in the current database that are used by some constraint.
Only those columns are shown that are contained in a table owned
the current user. For a check constraint, this view identifies the
columns that are used in the check expression. For a foreign key
constraint, this view identifies the columns that the foreign key
references. For a unique or primary key constraint, this view
identifies the constrained columns.
</para>
<table>
<title><literal>constraint_column_usage</literal> Columns</title>
<tgroup cols="3">
<thead>
<row>
<entry>Name</entry>
<entry>Data Type</entry>
<entry>Description</entry>
</row>
</thead>
<tbody>
<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 that is used by some constraint (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 that is used by some constraint
</entry>
</row>
<row>
<entry><literal>table_name</literal</entry>
<entry><type>sql_identifier</type></entry>
<entry>
Name of the table that contains the column that is used by some
constraint
</entry>
</row>
<row>
<entry><literal>column_name</literal</entry>
<entry><type>sql_identifier</type></entry>
<entry>
Name of the column that is used by some constraint
</entry>
</row>
<row>
<entry><literal>constraint_catalog</literal></entry>
<entry><type>sql_identifier</type></entry>
<entry>Name of the database that contains the constraint (always the current database)</entry>
</row>
<row>
<entry><literal>constraint_schema</literal</entry>
<entry><type>sql_identifier</type></entry>
<entry>Name of the schema that contains the constraint</entry>
</row>
<row>
<entry><literal>constraint_name</literal</entry>
<entry><type>sql_identifier</type></entry>
<entry>Name of the constraint</entry>
</row>
</tbody>
</tgroup>
</table>
</sect1>
<sect1 id="infoschema-constraint-table-usage">
<title><literal>constraint_table_usage</literal></title>
@ -605,9 +860,10 @@
<literal>table_constraints</literal>, which identifies all table
constraints along with the table they are defined on.) For a
foreign key constraint, this view identifies the table that the
foreign key references. Unique and primary key constraints simply
identify the table they belong to. Check constraints and not-null
constraints are not included in this view.
foreign key references. For a unique or primary key constraint,
this view simply identifies the table the constraint belongs to.
Check constraints and not-null constraints are not included in this
view.
</para>
<table>
@ -742,6 +998,69 @@
</table>
</sect1>
<sect1 id="infoschema-domain-udt-usage">
<title><literal>domain_udt_usage</literal></title>
<para>
The view <literal>domain_udt_usage</literal> identifies all columns
that use data types owned by the current user. Note that in
PostgreSQL, built-in data types behave like user-defined types, so
they are included here as well.
</para>
<table>
<title><literal>domain_udt_usage</literal> Columns</title>
<tgroup cols="3">
<thead>
<row>
<entry>Name</entry>
<entry>Data Type</entry>
<entry>Description</entry>
</row>
</thead>
<tbody>
<row>
<entry><literal>udt_catalog</literal></entry>
<entry><type>sql_identifier</type></entry>
<entry>Name of the database that the domain data type is defined in (always the current database)</entry>
</row>
<row>
<entry><literal>udt_schema</literal></entry>
<entry><type>sql_identifier</type></entry>
<entry>Name of the schema that the domain data type is defined in</entry>
</row>
<row>
<entry><literal>udt_name</literal></entry>
<entry><type>sql_identifier</type></entry>
<entry>Name of the domain data type</entry>
</row>
<row>
<entry><literal>domain_catalog</literal></entry>
<entry><type>sql_identifier</type></entry>
<entry>Name of the database that contains the domain (always the current database)</entry>
</row>
<row>
<entry><literal>domain_schema</literal</entry>
<entry><type>sql_identifier</type></entry>
<entry>Name of the schema that contains the domain</entry>
</row>
<row>
<entry><literal>domain_name</literal</entry>
<entry><type>sql_identifier</type></entry>
<entry>Name of the domain</entry>
</row>
</tbody>
</tgroup>
</table>
</sect1>
<sect1 id="infoschema-domains">
<title><literal>domains</literal></title>
@ -911,7 +1230,7 @@
<entry>Default expression of the domain</entry>
</row>
<row>
<row>
<entry><literal>udt_catalog</literal></entry>
<entry><type>sql_identifier</type></entry>
<entry>Name of the database that the domain data type is defined in (always the current database)</entry>
@ -967,6 +1286,97 @@
</table>
</sect1>
<sect1 id="infoschema-key-column-usage">
<title><literal>key_column_usage</literal></title>
<para>
The view <literal>key_column_usage</literal> identifies all columns
in the current database that are restricted by some unique, primary
key, or foreign key constraint. Check constraints are not included
in this view. Only those columns are shown that are contained in a
table owned the current user.
</para>
<table>
<title><literal>key_column_usage</literal> Columns</title>
<tgroup cols="3">
<thead>
<row>
<entry>Name</entry>
<entry>Data Type</entry>
<entry>Description</entry>
</row>
</thead>
<tbody>
<row>
<entry><literal>constraint_catalog</literal></entry>
<entry><type>sql_identifier</type></entry>
<entry>Name of the database that contains the constraint (always the current database)</entry>
</row>
<row>
<entry><literal>constraint_schema</literal</entry>
<entry><type>sql_identifier</type></entry>
<entry>Name of the schema that contains the constraint</entry>
</row>
<row>
<entry><literal>constraint_name</literal</entry>
<entry><type>sql_identifier</type></entry>
<entry>Name of the constraint</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 that is restricted by some constraint (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 that is restricted by some constraint
</entry>
</row>
<row>
<entry><literal>table_name</literal</entry>
<entry><type>sql_identifier</type></entry>
<entry>
Name of the table that contains the column that is restricted
by some constraint
</entry>
</row>
<row>
<entry><literal>column_name</literal</entry>
<entry><type>sql_identifier</type></entry>
<entry>
Name of the column that is restricted by some constraint
</entry>
</row>
<row>
<entry><literal>ordinal_position</literal</entry>
<entry><type>cardinal_number</type></entry>
<entry>
Ordinal position of the column within the constraint key (count
starts at 1)
</entry>
</row>
</tbody>
</tgroup>
</table>
</sect1>
<sect1 id="infoschema-parameters">
<title><literal>parameters</literal></title>
@ -1331,7 +1741,7 @@
<row>
<entry><literal>grantor</literal></entry>
<entry><type>sql_identifier</type></entry>
<entry>Name of the user that granted the privileges</entry>
<entry>Name of the user that granted the privilege</entry>
</row>
<row>
@ -2397,7 +2807,7 @@
<row>
<entry><literal>grantor</literal></entry>
<entry><type>sql_identifier</type></entry>
<entry>Name of the user that granted the privileges</entry>
<entry>Name of the user that granted the privilege</entry>
</row>
<row>
@ -2537,6 +2947,321 @@
</table>
</sect1>
<sect1 id="infoschema-triggers">
<title><literal>triggers</literal></title>
<para>
The view <literal>triggers</literal> contains all triggers defined
in the current database that are owned by the current user. (The
owner of the table is the owner of the trigger.)
</para>
<table>
<title><literal>triggers</literal> Columns</title>
<tgroup cols="3">
<thead>
<row>
<entry>Name</entry>
<entry>Data Type</entry>
<entry>Description</entry>
</row>
</thead>
<tbody>
<row>
<entry><literal>trigger_catalog</literal></entry>
<entry><type>sql_identifier</type></entry>
<entry>Name of the database that contains the trigger (always the current database)</entry>
</row>
<row>
<entry><literal>trigger_schema</literal</entry>
<entry><type>sql_identifier</type></entry>
<entry>Name of the schema that contains the trigger</entry>
</row>
<row>
<entry><literal>trigger_name</literal</entry>
<entry><type>sql_identifier</type></entry>
<entry>Name of the trigger</entry>
</row>
<row>
<entry><literal>event_manipulation</literal</entry>
<entry><type>character_data</type></entry>
<entry>
Event that fires the trigger (<literal>INSERT</literal>,
<literal>UPDATE</literal>, or <literal>DELETE</literal>)
</entry>
</row>
<row>
<entry><literal>event_object_catalog</literal></entry>
<entry><type>sql_identifier</type></entry>
<entry>
Name of the database that contains the table that the trigger
is defined on (always the current database)
</entry>
</row>
<row>
<entry><literal>event_object_schema</literal</entry>
<entry><type>sql_identifier</type></entry>
<entry>Name of the schema that contains the table that the trigger is defined on</entry>
</row>
<row>
<entry><literal>event_object_name</literal</entry>
<entry><type>sql_identifier</type></entry>
<entry>Name of the table that the trigger is defined on</entry>
</row>
<row>
<entry><literal>action_order</literal</entry>
<entry><type>cardinal_number</type></entry>
<entry>Not yet implemented</entry>
</row>
<row>
<entry><literal>action_condition</literal</entry>
<entry><type>character_data</type></entry>
<entry>Applies to a feature not available in PostgreSQL</entry>
</row>
<row>
<entry><literal>action_statement</literal</entry>
<entry><type>character_data</type></entry>
<entry>
Statement that is executed by the trigger (currently always
<literal>EXECUTE PROCEDURE
<replaceable>function</replaceable>(...)</literal>)
</entry>
</row>
<row>
<entry><literal>action_orientation</literal</entry>
<entry><type>character_data</type></entry>
<entry>
Identifies whether the trigger fires once for each processed
row or once for each statement (<literal>ROW</literal> or
<literal>STATEMENT</literal>)
</entry>
</row>
<row>
<entry><literal>condition_timing</literal</entry>
<entry><type>character_data</type></entry>
<entry>
Time at which the trigger fires (<literal>BEFORE</literal> or
<literal>AFTER</literal>)
</entry>
</row>
<row>
<entry><literal>condition_reference_old_table</literal</entry>
<entry><type>sql_identifier</type></entry>
<entry>Applies to a feature not available in PostgreSQL</entry>
</row>
<row>
<entry><literal>condition_reference_new_table</literal</entry>
<entry><type>sql_identifier</type></entry>
<entry>Applies to a feature not available in PostgreSQL</entry>
</row>
</tbody>
</tgroup>
</table>
<para>
Triggers in PostgreSQL have two incompatibilities with the SQL
standard that affect the representation in the information schema.
First, trigger names are local to the table in PostgreSQL, rather
than independent schema objects. Therefore there may be duplicate
trigger names defined in one schema, as long as they belong to
different tables. (<literal>trigger_catalog</literal> and
<literal>trigger_schema</literal> are really the values pertaining
to the table that the trigger is defined on.) Second, triggers can
be defined to fire on multiple events in PostgreSQL (e.g.,
<literal>ON INSERT OR UPDATE</literal>), whereas the SQL standard
only allows one. If a trigger is defined to fire on multiple
events, it is represented as multiple rows in the information
schema, one for each type of event. As a consequence of these two
issues, the primary key of the view <literal>triggers</literal> is
really <literal>(trigger_catalog, trigger_schema, trigger_name,
event_object_name, event_manipulation)</literal> instead of
<literal>(trigger_catalog, trigger_schema, trigger_name)</literal>,
which is what the SQL standard specifies. Nonetheless, if you
define your triggers in a manner that conforms with the SQL
standard (trigger names unique in the schema and only one event
type per trigger), this will not affect you.
</para>
</sect1>
<sect1 id="infoschema-view-column-usage">
<title><literal>view_column_usage</literal></title>
<para>
The view <literal>view_column_usage</literal> identifies all
columns that are used in the query expression of a view (the
<command>SELECT</command> statement that defines the view). A
column is only included if the current user is the owner of the
table that contains the column.
</para>
<note>
<para>
Columns of system tables are not included. This should be fixed
sometime.
</para>
</note>
<table>
<title><literal>view_column_usage</literal> Columns</title>
<tgroup cols="3">
<thead>
<row>
<entry>Name</entry>
<entry>Data Type</entry>
<entry>Description</entry>
</row>
</thead>
<tbody>
<row>
<entry><literal>view_catalog</literal></entry>
<entry><type>sql_identifier</type></entry>
<entry>Name of the database that contains the view (always the current database)</entry>
</row>
<row>
<entry><literal>view_schema</literal</entry>
<entry><type>sql_identifier</type></entry>
<entry>Name of the schema that contains the view</entry>
</row>
<row>
<entry><literal>view_name</literal</entry>
<entry><type>sql_identifier</type></entry>
<entry>Name of the view</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 that is used by the view (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 that is used by the view
</entry>
</row>
<row>
<entry><literal>table_name</literal</entry>
<entry><type>sql_identifier</type></entry>
<entry>
Name of the table that contains the column that is used by the
view
</entry>
</row>
<row>
<entry><literal>column_name</literal</entry>
<entry><type>sql_identifier</type></entry>
<entry>Name of the column that is used by the view</entry>
</row>
</tbody>
</tgroup>
</table>
</sect1>
<sect1 id="infoschema-view-table-usage">
<title><literal>view_table_usage</literal></title>
<para>
The view <literal>view_table_usage</literal> identifies all tables
that are used in the query expression of a view (the
<command>SELECT</command> statement that defines the view). A
table is only included if the current user is the owner of that
table.
</para>
<note>
<para>
System tables are not included. This should be fixed sometime.
</para>
</note>
<table>
<title><literal>view_table_usage</literal> Columns</title>
<tgroup cols="3">
<thead>
<row>
<entry>Name</entry>
<entry>Data Type</entry>
<entry>Description</entry>
</row>
</thead>
<tbody>
<row>
<entry><literal>view_catalog</literal></entry>
<entry><type>sql_identifier</type></entry>
<entry>Name of the database that contains the view (always the current database)</entry>
</row>
<row>
<entry><literal>view_schema</literal</entry>
<entry><type>sql_identifier</type></entry>
<entry>Name of the schema that contains the view</entry>
</row>
<row>
<entry><literal>view_name</literal</entry>
<entry><type>sql_identifier</type></entry>
<entry>Name of the view</entry>
</row>
<row>
<entry><literal>table_catalog</literal></entry>
<entry><type>sql_identifier</type></entry>
<entry>
Name of the database that contains the table the table that is
used by the view (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 is used by the
view
</entry>
</row>
<row>
<entry><literal>table_name</literal</entry>
<entry><type>sql_identifier</type></entry>
<entry>
Name of the table that is used by the view
</entry>
</row>
</tbody>
</tgroup>
</table>
</sect1>
<sect1 id="infoschema-views">
<title><literal>views</literal></title>

View File

@ -4,7 +4,7 @@
*
* Copyright 2002, PostgreSQL Global Development Group
*
* $Id: information_schema.sql,v 1.8 2003/06/11 09:23:55 petere Exp $
* $Id: information_schema.sql,v 1.9 2003/06/17 18:00:48 petere Exp $
*/
@ -78,13 +78,14 @@ CREATE VIEW check_constraints AS
CAST(con.consrc AS character_data) AS check_clause
FROM pg_namespace rs,
pg_constraint con
LEFT OUTER JOIN pg_class c on (c.oid = con.conrelid)
LEFT OUTER JOIN pg_type t on (t.oid = con.contypid),
LEFT OUTER JOIN pg_class c ON (c.oid = con.conrelid)
LEFT OUTER JOIN pg_type t ON (t.oid = con.contypid),
pg_user u
WHERE rs.oid = con.connamespace
AND u.usesysid = coalesce(c.relowner, t.typowner)
AND u.usename = current_user
AND con.contype = 'c';
AND con.contype = 'c'
AND c.relkind = 'r';
GRANT SELECT ON check_constraints TO PUBLIC;
@ -106,9 +107,15 @@ CREATE VIEW column_domain_usage AS
FROM pg_type t, pg_namespace nt, pg_class c, pg_namespace nc,
pg_attribute a, pg_user u
WHERE t.typnamespace = nt.oid AND t.typtype = 'd'
AND c.relnamespace = nc.oid AND a.attrelid = c.oid
AND a.atttypid = t.oid AND t.typowner = u.usesysid
WHERE t.typnamespace = nt.oid
AND c.relnamespace = nc.oid
AND a.attrelid = c.oid
AND a.atttypid = t.oid
AND t.typowner = u.usesysid
AND t.typtype = 'd'
AND c.relkind IN ('r', 'v')
AND a.attnum > 0
AND NOT a.attisdropped
AND u.usename = current_user;
GRANT SELECT ON column_domain_usage TO PUBLIC;
@ -119,23 +126,70 @@ GRANT SELECT ON column_domain_usage TO PUBLIC;
* COLUMN_PRIVILEGES
*/
-- PostgreSQL does not have column privileges, so this view is empty.
-- (Table privileges do not also count as column privileges.)
CREATE VIEW column_privileges AS
SELECT CAST(null AS sql_identifier) AS grantor,
CAST(null AS sql_identifier) AS grantee,
CAST(null AS sql_identifier) AS table_catalog,
CAST(null AS sql_identifier) AS table_schema,
CAST(null AS sql_identifier) AS table_name,
CAST(null AS sql_identifier) AS column_name,
CAST(null AS character_data) AS privilege_type,
CAST(null AS character_data) AS is_grantable
WHERE false;
SELECT CAST(u_grantor.usename AS sql_identifier) AS grantor,
CAST(u_grantee.usename 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(u_grantee.usesysid, 0, 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)
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(u_grantee.usesysid, 0, u_grantor.usesysid, pr.type, false))
AND (u_grantor.usename = current_user
OR u_grantee.usename = current_user
OR u_grantee.usename = 'PUBLIC');
GRANT SELECT ON column_privileges TO PUBLIC;
/*
* 20.17
* COLUMN_UDT_USAGE view
*/
CREATE VIEW column_udt_usage AS
SELECT CAST(current_database() AS sql_identifier) AS udt_catalog,
CAST(coalesce(nbt.nspname, nt.nspname) AS sql_identifier) AS udt_schema,
CAST(coalesce(bt.typname, t.typname) AS sql_identifier) AS udt_name,
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
FROM pg_attribute a, pg_class c, pg_namespace nc, pg_user u,
(pg_type t JOIN pg_namespace nt ON (t.typnamespace = nt.oid))
LEFT JOIN (pg_type bt JOIN pg_namespace nbt ON (bt.typnamespace = nbt.oid))
ON (t.typtype = 'd' AND t.typbasetype = bt.oid)
WHERE a.attrelid = c.oid
AND a.atttypid = t.oid
AND u.usesysid = coalesce(bt.typowner, t.typowner)
AND nc.oid = c.relnamespace
AND a.attnum > 0 AND NOT a.attisdropped AND c.relkind in ('r', 'v')
AND u.usename = current_user;
GRANT SELECT ON column_udt_usage TO PUBLIC;
/*
* 20.18
* COLUMNS view
@ -305,9 +359,6 @@ GRANT SELECT ON columns TO PUBLIC;
* CONSTRAINT_COLUMN_USAGE view
*/
-- FIXME: This only works for check constraints so far; for the others
-- we need a built-in way to convert arrays to virtual tables.
CREATE VIEW constraint_column_usage AS
SELECT CAST(current_database() AS sql_identifier) AS table_catalog,
CAST(tblschema AS sql_identifier) AS table_schema,
@ -318,6 +369,7 @@ CREATE VIEW constraint_column_usage AS
CAST(cstrname AS sql_identifier) AS constraint_name
FROM (
/* check constraints */
SELECT DISTINCT nr.nspname, r.relname, r.relowner, a.attname, nc.nspname, c.conname
FROM pg_namespace nr, pg_class r, pg_attribute a, pg_depend d, pg_namespace nc, pg_constraint c
WHERE nr.oid = r.relnamespace
@ -329,6 +381,33 @@ CREATE VIEW constraint_column_usage AS
AND d.objid = c.oid
AND c.connamespace = nc.oid
AND c.contype = 'c'
AND r.relkind = 'r'
AND a.attnum > 0
AND NOT a.attisdropped
UNION
/* unique/primary key/foreign key constraints */
SELECT nr.nspname, r.relname, r.relowner, a.attname, nc.nspname, c.conname
FROM pg_namespace nr, pg_class r, pg_attribute a, pg_namespace nc, pg_constraint c,
(select 1 union select 2 union select 3 union select 4 union select 5 union
select 6 union select 7 union select 8 union select 9 union select 10 union
select 11 union select 12 union select 13 union select 14 union select 15 union
select 16 union select 17 union select 18 union select 19 union select 20 union
select 21 union select 22 union select 23 union select 24 union select 25 union
select 26 union select 27 union select 28 union select 29 union select 30 union
select 31 union select 32) AS pos(n)
WHERE nr.oid = r.relnamespace
AND r.oid = a.attrelid
AND r.oid = c.conrelid
AND nc.oid = c.connamespace
AND (CASE WHEN c.contype = 'f' THEN c.confkey[pos.n] = a.attnum
ELSE c.conkey[pos.n] = a.attnum END)
AND a.attnum > 0
AND NOT a.attisdropped
AND c.contype IN ('p', 'u', 'f')
AND r.relkind = 'r'
) AS x (tblschema, tblname, tblowner, colname, cstrschema, cstrname),
pg_user u
@ -357,6 +436,7 @@ CREATE VIEW constraint_table_usage AS
WHERE c.connamespace = nc.oid AND r.relnamespace = nr.oid
AND ( (c.contype = 'f' AND c.confrelid = r.oid)
OR (c.contype IN ('p', 'u') AND c.conrelid = r.oid) )
AND r.relkind = 'r'
AND r.relowner = u.usesysid AND u.usename = current_user;
GRANT SELECT ON constraint_table_usage TO PUBLIC;
@ -388,6 +468,33 @@ CREATE VIEW domain_constraints AS
GRANT SELECT ON domain_constraints TO PUBLIC;
/*
* 20.25
* DOMAIN_UDT_USAGE view
*/
CREATE VIEW domain_udt_usage AS
SELECT CAST(current_database() AS sql_identifier) AS udt_catalog,
CAST(nbt.nspname AS sql_identifier) AS udt_schema,
CAST(bt.typname AS sql_identifier) AS udt_name,
CAST(current_database() AS sql_identifier) AS domain_catalog,
CAST(nt.nspname AS sql_identifier) AS domain_schema,
CAST(t.typname AS sql_identifier) AS domain_name
FROM pg_type t, pg_namespace nt,
pg_type bt, pg_namespace nbt,
pg_user u
WHERE t.typnamespace = nt.oid
AND t.typbasetype = bt.oid
AND bt.typnamespace = nbt.oid
AND t.typtype = 'd'
AND bt.typowner = u.usesysid
AND u.usename = current_user;
GRANT SELECT ON domain_udt_usage TO PUBLIC;
/*
* 20.26
* DOMAINS view
@ -487,6 +594,46 @@ CREATE VIEW domains AS
GRANT SELECT ON domains TO PUBLIC;
/*
* 20.30
* KEY_COLUMN_USAGE view
*/
CREATE VIEW key_column_usage AS
SELECT CAST(current_database() AS sql_identifier) AS constraint_catalog,
CAST(nc.nspname AS sql_identifier) AS constraint_schema,
CAST(c.conname AS sql_identifier) AS constraint_name,
CAST(current_database() AS sql_identifier) AS table_catalog,
CAST(nr.nspname AS sql_identifier) AS table_schema,
CAST(r.relname AS sql_identifier) AS table_name,
CAST(a.attname AS sql_identifier) AS column_name,
CAST(pos.n AS cardinal_number) AS ordinal_position
FROM pg_namespace nr, pg_class r, pg_attribute a, pg_namespace nc, pg_constraint c,
pg_user u,
(select 1 union select 2 union select 3 union select 4 union select 5 union
select 6 union select 7 union select 8 union select 9 union select 10 union
select 11 union select 12 union select 13 union select 14 union select 15 union
select 16 union select 17 union select 18 union select 19 union select 20 union
select 21 union select 22 union select 23 union select 24 union select 25 union
select 26 union select 27 union select 28 union select 29 union select 30 union
select 31 union select 32) AS pos(n)
WHERE nr.oid = r.relnamespace
AND r.oid = a.attrelid
AND r.oid = c.conrelid
AND nc.oid = c.connamespace
AND c.conkey[pos.n] = a.attnum
AND a.attnum > 0
AND NOT a.attisdropped
AND c.contype IN ('p', 'u', 'f')
AND r.relkind = 'r'
AND r.relowner = u.usesysid
AND u.usename = current_user;
GRANT SELECT ON key_column_usage TO PUBLIC;
/*
* 20.33
* PARAMETERS view
@ -593,6 +740,7 @@ CREATE VIEW referential_constraints AS
AND con.confkey = pkc.conkey
AND pkc.connamespace = npkc.oid
AND c.relowner = u.usesysid
AND c.relkind = 'r'
AND u.usename = current_user;
GRANT SELECT ON referential_constraints TO PUBLIC;
@ -932,6 +1080,7 @@ CREATE VIEW table_constraints AS
WHERE nc.oid = c.connamespace AND nr.oid = r.relnamespace
AND c.conrelid = r.oid AND r.relowner = u.usesysid
AND r.relkind = 'r'
AND u.usename = current_user;
-- FIMXE: Not-null constraints are missing here.
@ -965,6 +1114,7 @@ CREATE VIEW table_privileges AS
UNION SELECT 'REFERENCES' 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))
AND (u_grantor.usename = current_user
@ -1014,6 +1164,68 @@ CREATE VIEW tables AS
GRANT SELECT ON tables TO PUBLIC;
/*
* 20.59
* TRIGGERED_UPDATE_COLUMNS view
*/
-- PostgreSQL doesn't allow the specification of individual triggered
-- update columns, so this view is empty.
CREATE VIEW triggered_update_columns AS
SELECT CAST(current_database() AS sql_identifier) AS trigger_catalog,
CAST(null AS sql_identifier) AS trigger_schema,
CAST(null AS sql_identifier) AS trigger_name,
CAST(current_database() AS sql_identifier) AS event_object_catalog,
CAST(null AS sql_identifier) AS event_object_schema,
CAST(null AS sql_identifier) AS event_object_table,
CAST(null AS sql_identifier) AS event_object_column
WHERE false;
GRANT SELECT ON triggered_update_columns TO PUBLIC;
/*
* 20.62
* TRIGGERS view
*/
CREATE VIEW triggers AS
SELECT CAST(current_database() AS sql_identifier) AS trigger_catalog,
CAST(n.nspname AS sql_identifier) AS trigger_schema,
CAST(t.tgname AS sql_identifier) AS trigger_name,
CAST(em.text AS character_data) AS event_manipulation,
CAST(current_database() AS sql_identifier) AS event_object_catalog,
CAST(n.nspname AS sql_identifier) AS event_object_schema,
CAST(c.relname AS sql_identifier) AS event_object_table,
CAST(null AS cardinal_number) AS action_order,
CAST(null AS character_data) AS action_condition,
CAST(
substring(pg_get_triggerdef(t.oid) from
position('EXECUTE PROCEDURE' in substring(pg_get_triggerdef(t.oid) from 48)) + 47)
AS character_data) AS action_statement,
CAST(
CASE WHEN t.tgtype & 1 = 1 THEN 'ROW' ELSE 'STATEMENT' END
AS character_data) AS action_orientation,
CAST(
CASE WHEN t.tgtype & 2 = 2 THEN 'BEFORE' ELSE 'AFTER' END
AS character_data) AS condition_timing,
CAST(null AS sql_identifier) AS condition_reference_old_table,
CAST(null AS sql_identifier) AS condition_reference_new_table
FROM pg_namespace n, pg_class c, pg_trigger t, pg_user u,
(SELECT 4, 'INSERT' UNION SELECT 8, 'DELETE' UNION SELECT 16, 'UPDATE') AS em (num, text)
WHERE n.oid = c.relnamespace
AND c.oid = t.tgrelid
AND c.relowner = u.usesysid
AND t.tgtype & em.num <> 0
AND NOT t.tgisconstraint
AND u.usename = current_user;
GRANT SELECT ON triggers TO PUBLIC;
/*
* 20.63
* USAGE_PRIVILEGES view
@ -1044,6 +1256,81 @@ CREATE VIEW usage_privileges AS
GRANT SELECT ON usage_privileges TO PUBLIC;
/*
* 20.65
* VIEW_COLUMN_USAGE
*/
CREATE VIEW view_column_usage AS
SELECT DISTINCT
CAST(current_database() AS sql_identifier) AS view_catalog,
CAST(nv.nspname AS sql_identifier) AS view_schema,
CAST(v.relname AS sql_identifier) AS view_name,
CAST(current_database() AS sql_identifier) AS table_catalog,
CAST(nt.nspname AS sql_identifier) AS table_schema,
CAST(t.relname AS sql_identifier) AS table_name,
CAST(a.attname AS sql_identifier) AS column_name
FROM pg_user, pg_namespace nv, pg_class v, pg_depend dv,
pg_depend dt, pg_class t, pg_namespace nt,
pg_attribute a, pg_user u
WHERE nv.oid = v.relnamespace
AND v.relkind = 'v'
AND v.oid = dv.refobjid
AND dv.refclassid = (SELECT oid FROM pg_class WHERE relname = 'pg_class')
AND dv.classid = (SELECT oid FROM pg_class WHERE relname = 'pg_rewrite')
AND dv.deptype = 'i'
AND dv.objid = dt.objid
AND dv.refobjid <> dt.refobjid
AND dt.classid = (SELECT oid FROM pg_class WHERE relname = 'pg_rewrite')
AND dt.refclassid = (SELECT oid FROM pg_class WHERE relname = 'pg_class')
AND dt.refobjid = t.oid
AND t.relnamespace = nt.oid
AND t.relkind IN ('r', 'v')
AND t.oid = a.attrelid
AND dt.refobjsubid = a.attnum
AND t.relowner = u.usesysid AND u.usename = current_user;
GRANT SELECT ON view_column_usage TO PUBLIC;
/*
* 20.66
* VIEW_TABLE_USAGE
*/
CREATE VIEW view_table_usage AS
SELECT DISTINCT
CAST(current_database() AS sql_identifier) AS view_catalog,
CAST(nv.nspname AS sql_identifier) AS view_schema,
CAST(v.relname AS sql_identifier) AS view_name,
CAST(current_database() AS sql_identifier) AS table_catalog,
CAST(nt.nspname AS sql_identifier) AS table_schema,
CAST(t.relname AS sql_identifier) AS table_name
FROM pg_user, pg_namespace nv, pg_class v, pg_depend dv,
pg_depend dt, pg_class t, pg_namespace nt,
pg_user u
WHERE nv.oid = v.relnamespace
AND v.relkind = 'v'
AND v.oid = dv.refobjid
AND dv.refclassid = (SELECT oid FROM pg_class WHERE relname = 'pg_class')
AND dv.classid = (SELECT oid FROM pg_class WHERE relname = 'pg_rewrite')
AND dv.deptype = 'i'
AND dv.objid = dt.objid
AND dv.refobjid <> dt.refobjid
AND dt.classid = (SELECT oid FROM pg_class WHERE relname = 'pg_rewrite')
AND dt.refclassid = (SELECT oid FROM pg_class WHERE relname = 'pg_class')
AND dt.refobjid = t.oid
AND t.relnamespace = nt.oid
AND t.relkind IN ('r', 'v')
AND t.relowner = u.usesysid AND u.usename = current_user;
GRANT SELECT ON view_table_usage TO PUBLIC;
/*
* 20.68
* VIEWS view