Commit 2f80f81e authored by Peter Eisentraut's avatar Peter Eisentraut

Make information schema aware of arrays.

The view element_types is currently not functional, awaiting some fixes in
the planner (reported on -hackers).
parent c1fad341
<!-- $Header: /cvsroot/pgsql/doc/src/sgml/information_schema.sgml,v 1.4 2003/06/17 18:00:48 petere Exp $ -->
<!-- $Header: /cvsroot/pgsql/doc/src/sgml/information_schema.sgml,v 1.5 2003/06/28 20:50:07 petere Exp $ -->
<chapter id="information-schema">
<title>The Information Schema</title>
......@@ -509,7 +509,9 @@
<entry><literal>data_type</literal></entry>
<entry><type>character_data</type></entry>
<entry>
Data type of the column, if it is a built-in type, else
Data type of the column, if it is a built-in type, or
<literal>ARRAY</literal> if it is some array (in that case, see
the view <literal>element_types</literal>), else
<literal>USER-DEFINED</literal> (in that case, the type is
identified in <literal>udt_name</literal> and associated
columns). If the column is based on a domain, this column
......@@ -713,16 +715,19 @@
<row>
<entry><literal>maximum_cardinality</literal></entry>
<entry><type>cardinal_number</type></entry>
<entry>Applies to a feature not available in PostgreSQL</entry>
<entry>Always null, because arrays always have unlimited maximum cardinality in PostgreSQL</entry>
</row>
<row>
<entry><literal>dtd_identifier</literal></entry>
<entry><type>sql_identifier</type></entry>
<entry>
A unique identifier of the data type of the column (The
specific format of the identifier is not defined and not
guaranteed to remain the same in future versions.)
An identifier of the data type descriptor of the column, unique
among the data type descriptors pertaining to the table. This
is mainly useful for joining with other instances of such
identifiers. (The specific format of the identifier is not
defined and not guaranteed to remain the same in future
versions.)
</entry>
</row>
......@@ -759,9 +764,7 @@
and <literal>domain_catalog</literal>. If you want to pair up
columns with their associated data types and treat domains as
separate types, you could write <literal>coalesce(domain_name,
udt_name)</literal>, etc. Finally, if you want to check whether
two columns have the same type, use
<literal>dtd_identifier</literal>.
udt_name)</literal>, etc.
</para>
</sect1>
......@@ -925,6 +928,82 @@
</table>
</sect1>
<sect1 id="infoschema-data-type-privileges">
<title><literal>data_type_privileges</literal></title>
<para>
The view <literal>data_type_privileges</literal> identifies all
data type descriptors that the current user has access to, by way
of being the owner of the described object or having some privilege
for it. A data type descriptor is generated whenever a data type
is used in the definition of a table column, a domain, or a
function (as parameter or return type) and stores some information
about how the data type is used in that instance (for example, the
declared maximum length, if applicable). Each data type
descriptors is assigned an arbitrary identifier that is unique
among the data type descriptor identifiers assigned for one object
(table, domain, function). This view is probably not useful for
applications, but it is used to define some other views in the
information schema.
</para>
<table>
<title><literal>domain_constraints</literal> Columns</title>
<tgroup cols="3">
<thead>
<row>
<entry>Name</entry>
<entry>Data Type</entry>
<entry>Description</entry>
</row>
</thead>
<tbody>
<row>
<entry><literal>object_catalog</literal></entry>
<entry><type>sql_identifier</type></entry>
<entry>Name of the database that contains the described 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 that contains the described object</entry>
</row>
<row>
<entry><literal>object_name</literal</entry>
<entry><type>sql_identifier</type></entry>
<entry>Name of the described object</entry>
</row>
<row>
<entry><literal>object_type</literal</entry>
<entry><type>character_data</type></entry>
<entry>
The type of the described object: one of
<literal>TABLE</literal> (the data type descriptor pertains to
a column of that table), <literal>DOMAIN</literal> (the data
type descriptors pertains to that domain),
<literal>ROUTINE</literal> (the data type descriptor pertains
to a parameter or the return data type of that function).
</entry>
</row>
<row>
<entry><literal>dtd_identifier</literal</entry>
<entry><type>sql_identifier</type></entry>
<entry>
The identifier of the data type descriptor, which is unique
among the data type descriptors for that same object.
</entry>
</row>
</tbody>
</tgroup>
</table>
</sect1>
<sect1 id="infoschema-domain-constraints">
<title><literal>domain_constraints</literal></title>
......@@ -1103,7 +1182,14 @@
<row>
<entry><literal>data_type</literal></entry>
<entry><type>character_data</type></entry>
<entry>Data type of the domain</entry>
<entry>
Data type of the domain, if it is a built-in type, or
<literal>ARRAY</literal> if it is some array (in that case, see
the view <literal>element_types</literal>), else
<literal>USER-DEFINED</literal> (in that case, the type is
identified in <literal>udt_name</literal> and associated
columns).
</entry>
</row>
<row>
......@@ -1269,16 +1355,271 @@
<row>
<entry><literal>maximum_cardinality</literal></entry>
<entry><type>cardinal_number</type></entry>
<entry>Always null, because arrays always have unlimited maximum cardinality in PostgreSQL</entry>
</row>
<row>
<entry><literal>dtd_identifier</literal></entry>
<entry><type>sql_identifier</type></entry>
<entry>
An identifier of the data type descriptor of the domain, unique
among the data type descriptors pertaining to the domain (which
is trivial, because a domain only contains one data type
descriptor). This is mainly useful for joining with other
instances of such identifiers. (The specific format of the
identifier is not defined and not guaranteed to remain the same
in future versions.)
</entry>
</row>
</tbody>
</tgroup>
</table>
</sect1>
<sect1 id="infoschema-element-types">
<title><literal>element_types</literal></title>
<para>
The view <literal>element_types</literal> contains the data type
descriptors of the elements of arrays. When a table column,
domain, function parameter, or function return value is defined to
be of an array type, the respective information schema view only
contains <literal>ARRAY</literal> in the column
<literal>data_type</literal>. To obtain information on the element
type of the array, you can join the respective view with this view.
For example, to show the columns of a table with data types and
array element types, if applicable, you could do
<programlisting>
SELECT c.column_name, c.data_type, e.data_type AS element_type
FROM information_schema.columns c LEFT JOIN information_schema.element_types e
ON ((c.table_catalog, c.table_schema, c.table_name, 'TABLE', c.dtd_identifier)
= (e.object_catalog, e.object_schema, e.object_name, e.object_type, e.array_type_identifier))
WHERE c.table_schema = '...' AND c.table_name = '...'
ORDER BY c.ordinal_position;
</programlisting>
This view only includes objects that the current user has access
to, by way of being the owner or having some privilege.
</para>
<table>
<title><literal>element_types</literal> Columns</title>
<tgroup cols="3">
<thead>
<row>
<entry>Name</entry>
<entry>Data Type</entry>
<entry>Description</entry>
</row>
</thead>
<tbody>
<row>
<entry><literal>object_catalog</literal></entry>
<entry><type>sql_identifier</type></entry>
<entry>
Name of the database that contains the object that uses the
array being described (always the current database)
</entry>
</row>
<row>
<entry><literal>object_schema</literal</entry>
<entry><type>sql_identifier</type></entry>
<entry>
Name of the schema that contains the object that uses the array
being described
</entry>
</row>
<row>
<entry><literal>object_name</literal</entry>
<entry><type>sql_identifier</type></entry>
<entry>
Name of the object that uses the array being described
</entry>
</row>
<row>
<entry><literal>object_type</literal</entry>
<entry><type>character_data</type></entry>
<entry>
The type of the object that uses the array being descibed: one
of <literal>TABLE</literal> (the array is used by a column of
that table), <literal>DOMAIN</literal> (the array is used by
that domain), <literal>ROUTINE</literal> (the array is used by
a parameter or the return data type of that function).
</entry>
</row>
<row>
<entry><literal>array_type_identifier</literal</entry>
<entry><type>sql_identifier</type></entry>
<entry>
The identifier of the data type descriptor of the array being
described. Use this to join with the
<literal>dtd_identifier</literal> columns of other information
schema views.
</entry>
</row>
<row>
<entry><literal>data_type</literal></entry>
<entry><type>character_data</type></entry>
<entry>
Data type of the array elements, if it is a built-in type, else
<literal>USER-DEFINED</literal> (in that case, the type is
identified in <literal>udt_name</literal> and associated
columns).
</entry>
</row>
<row>
<entry><literal>character_maximum_length</literal></entry>
<entry><type>cardinal_number</type></entry>
<entry>Always null, since this information is not applied to array element data types in PostgreSQL</entry>
</row>
<row>
<entry><literal>character_octet_length</literal></entry>
<entry><type>cardinal_number</type></entry>
<entry>Always null, since this information is not applied to array element data types in PostgreSQL</entry>
</row>
<row>
<entry><literal>character_set_catalog</literal></entry>
<entry><type>sql_identifier</type></entry>
<entry>Applies to a feature not available in PostgreSQL</entry>
</row>
<row>
<entry><literal>character_set_schema</literal></entry>
<entry><type>sql_identifier</type></entry>
<entry>Applies to a feature not available in PostgreSQL</entry>
</row>
<row>
<entry><literal>character_set_name</literal></entry>
<entry><type>sql_identifier</type></entry>
<entry>Applies to a feature not available in PostgreSQL</entry>
</row>
<row>
<entry><literal>collation_catalog</literal></entry>
<entry><type>sql_identifier</type></entry>
<entry>Applies to a feature not available in PostgreSQL</entry>
</row>
<row>
<entry><literal>collation_schema</literal></entry>
<entry><type>sql_identifier</type></entry>
<entry>Applies to a feature not available in PostgreSQL</entry>
</row>
<row>
<entry><literal>collation_name</literal></entry>
<entry><type>sql_identifier</type></entry>
<entry>Applies to a feature not available in PostgreSQL</entry>
</row>
<row>
<entry><literal>numeric_precision</literal></entry>
<entry><type>cardinal_number</type></entry>
<entry>Always null, since this information is not applied to array element data types in PostgreSQL</entry>
</row>
<row>
<entry><literal>numeric_precision_radix</literal></entry>
<entry><type>cardinal_number</type></entry>
<entry>Always null, since this information is not applied to array element data types in PostgreSQL</entry>
</row>
<row>
<entry><literal>numeric_scale</literal></entry>
<entry><type>cardinal_number</type></entry>
<entry>Always null, since this information is not applied to array element data types in PostgreSQL</entry>
</row>
<row>
<entry><literal>datetime_precision</literal></entry>
<entry><type>cardinal_number</type></entry>
<entry>Always null, since this information is not applied to array element data types in PostgreSQL</entry>
</row>
<row>
<entry><literal>interval_type</literal></entry>
<entry><type>character_data</type></entry>
<entry>Always null, since this information is not applied to array element data types in PostgreSQL</entry>
</row>
<row>
<entry><literal>interval_precision</literal></entry>
<entry><type>character_data</type></entry>
<entry>Always null, since this information is not applied to array element data types in PostgreSQL</entry>
</row>
<row>
<entry><literal>domain_default</literal></entry>
<entry><type>character_data</type></entry>
<entry>Not yet implemented</entry>
</row>
<row>
<entry><literal>udt_catalog</literal></entry>
<entry><type>sql_identifier</type></entry>
<entry>
Name of the database that the data type of the elements 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 data type of the elements is
defined in
</entry>
</row>
<row>
<entry><literal>udt_name</literal></entry>
<entry><type>sql_identifier</type></entry>
<entry>
Name of the data type of the elements
</entry>
</row>
<row>
<entry><literal>scope_catalog</literal></entry>
<entry><type>sql_identifier</type></entry>
<entry>Applies to a feature not available in PostgreSQL</entry>
</row>
<row>
<entry><literal>scope_schema</literal></entry>
<entry><type>sql_identifier</type></entry>
<entry>Applies to a feature not available in PostgreSQL</entry>
</row>
<row>
<entry><literal>scope_name</literal></entry>
<entry><type>sql_identifier</type></entry>
<entry>Applies to a feature not available in PostgreSQL</entry>
</row>
<row>
<entry><literal>maximum_cardinality</literal></entry>
<entry><type>cardinal_number</type></entry>
<entry>Always null, because arrays always have unlimited maximum cardinality in PostgreSQL</entry>
</row>
<row>
<entry><literal>dtd_identifier</literal></entry>
<entry><type>sql_identifier</type></entry>
<entry>
A unique identifier of the data type of the domain (The
specific format of the identifier is not defined and not
guaranteed to remain the same in future versions.)
An identifier of the data type descriptor of the element. This
is currently not useful.
</entry>
</row>
</tbody>
......@@ -1460,7 +1801,14 @@
<row>
<entry><literal>data_type</literal></entry>
<entry><type>character_data</type></entry>
<entry>Data type of the parameter</entry>
<entry>
Data type of the parameter, if it is a built-in type, or
<literal>ARRAY</literal> if it is some array (in that case, see
the view <literal>element_types</literal>), else
<literal>USER-DEFINED</literal> (in that case, the type is
identified in <literal>udt_name</literal> and associated
columns).
</entry>
</row>
<row>
......@@ -1594,16 +1942,19 @@
<row>
<entry><literal>maximum_cardinality</literal></entry>
<entry><type>cardinal_number</type></entry>
<entry>Applies to a feature not available in PostgreSQL</entry>
<entry>Always null, because arrays always have unlimited maximum cardinality in PostgreSQL</entry>
</row>
<row>
<entry><literal>dtd_identifier</literal></entry>
<entry><type>sql_identifier</type></entry>
<entry>
A unique identifier of the data type of the parameter (The
specific format of the identifier is not defined and not
guaranteed to remain the same in future versions.)
An identifier of the data type descriptor of the parameter,
unique among the data type descriptors pertaining to the
function. This is mainly useful for joining with other
instances of such identifiers. (The specific format of the
identifier is not defined and not guaranteed to remain the same
in future versions.)
</entry>
</row>
</tbody>
......@@ -1918,7 +2269,14 @@
<row>
<entry><literal>data_type</literal></entry>
<entry><type>character_data</type></entry>
<entry>Return data type of the function</entry>
<entry>
Return data type of the function, if it is a built-in type, or
<literal>ARRAY</literal> if it is some array (in that case, see
the view <literal>element_types</literal>), else
<literal>USER-DEFINED</literal> (in that case, the type is
identified in <literal>type_udt_name</literal> and associated
columns).
</entry>
</row>
<row>
......@@ -2052,16 +2410,19 @@
<row>
<entry><literal>maximum_cardinality</literal></entry>
<entry><type>cardinal_number</type></entry>
<entry>Applies to a feature not available in PostgreSQL</entry>
<entry>Always null, because arrays always have unlimited maximum cardinality in PostgreSQL</entry>
</row>
<row>
<entry><literal>dtd_identifier</literal></entry>
<entry><type>sql_identifier</type></entry>
<entry>
A unique identifier of the return data type of the function
(The specific format of the identifier is not defined and not
guaranteed to remain the same in future versions.)
An identifier of the data type descriptor of the return data
type of this function, unique among the data type descriptors
pertaining to the function. This is mainly useful for joining
with other instances of such identifiers. (The specific format
of the identifier is not defined and not guaranteed to remain
the same in future versions.)
</entry>
</row>
......
......@@ -2,9 +2,18 @@
* SQL Information Schema
* as defined in ISO 9075-2:1999 chapter 20
*
* Copyright 2002, PostgreSQL Global Development Group
* Copyright 2003, PostgreSQL Global Development Group
*
* $Id: information_schema.sql,v 1.9 2003/06/17 18:00:48 petere Exp $
* $Id: information_schema.sql,v 1.10 2003/06/28 20:50:08 petere Exp $
*/
/*
* Note: Generally, the definitions in this file should be ordered
* according to the clause numbers in the SQL standard, which is also the
* alphabetical order. In some cases it is convenient or necessary to
* define one information schema view by using another one; in that case,
* put the referencing view at the very end and leave a note where it
* should have been put.
*/
......@@ -18,7 +27,7 @@ GRANT USAGE ON SCHEMA information_schema TO PUBLIC;
SET search_path TO information_schema, public;
-- Note: 20.3 follows later. Some genius screwed up the order in the standard.
-- 20.3 INFORMATION_SCHEMA_CATALOG_NAME view appears later.
/*
......@@ -211,12 +220,12 @@ CREATE VIEW columns AS
CAST(
CASE WHEN t.typtype = 'd' THEN
CASE WHEN nbt.nspname = 'pg_catalog'
THEN format_type(t.typbasetype, null)
CASE WHEN bt.typelem <> 0 AND bt.typlen = -1 THEN 'ARRAY'
WHEN nbt.nspname = 'pg_catalog' THEN format_type(t.typbasetype, null)
ELSE 'USER-DEFINED' END
ELSE
CASE WHEN nt.nspname = 'pg_catalog'
THEN format_type(a.atttypid, null)
CASE WHEN t.typelem <> 0 AND t.typlen = -1 THEN 'ARRAY'
WHEN nt.nspname = 'pg_catalog' THEN format_type(a.atttypid, null)
ELSE 'USER-DEFINED' END
END
AS character_data)
......@@ -326,7 +335,7 @@ CREATE VIEW columns AS
CAST(null AS sql_identifier) AS scope_name,
CAST(null AS cardinal_number) AS maximum_cardinality,
CAST(t.oid AS sql_identifier) AS dtd_identifier,
CAST(a.attnum AS sql_identifier) AS dtd_identifier,
CAST('NO' AS character_data) AS is_self_referencing
FROM (pg_attribute LEFT JOIN pg_attrdef ON attrelid = adrelid AND attnum = adnum) AS a,
......@@ -442,6 +451,9 @@ CREATE VIEW constraint_table_usage AS
GRANT SELECT ON constraint_table_usage TO PUBLIC;
-- 20.21 DATA_TYPE_PRIVILEGES view appears later.
/*
* 20.24
* DOMAIN_CONSTRAINTS view
......@@ -506,9 +518,9 @@ CREATE VIEW domains AS
CAST(t.typname AS sql_identifier) AS domain_name,
CAST(
CASE WHEN nbt.nspname = 'pg_catalog'
THEN format_type(t.typbasetype, null)
ELSE 'USER-DEFINED' END
CASE WHEN t.typelem <> 0 AND t.typlen = -1 THEN 'ARRAY'
WHEN nbt.nspname = 'pg_catalog' THEN format_type(t.typbasetype, null)
ELSE 'USER-DEFINED' END
AS character_data)
AS data_type,
......@@ -581,7 +593,7 @@ CREATE VIEW domains AS
CAST(null AS sql_identifier) AS scope_name,
CAST(null AS cardinal_number) AS maximum_cardinality,
CAST(t.oid AS sql_identifier) AS dtd_identifier
CAST(1 AS sql_identifier) AS dtd_identifier
FROM pg_type t, pg_namespace nt,
pg_type bt, pg_namespace nbt
......@@ -594,6 +606,9 @@ CREATE VIEW domains AS
GRANT SELECT ON domains TO PUBLIC;
-- 20.27 ELEMENT_TYPES view appears later.
/*
* 20.30
* KEY_COLUMN_USAGE view
......@@ -649,8 +664,8 @@ CREATE VIEW parameters AS
CAST('NO' AS character_data) AS as_locator,
CAST(null AS sql_identifier) AS parameter_name,
CAST(
CASE WHEN nt.nspname = 'pg_catalog'
THEN format_type(t.oid, null)
CASE WHEN t.typelem <> 0 AND t.typlen = -1 THEN 'ARRAY'
WHEN nt.nspname = 'pg_catalog' THEN format_type(t.oid, null)
ELSE 'USER-DEFINED' END AS character_data)
AS data_type,
CAST(null AS cardinal_number) AS character_maximum_length,
......@@ -674,7 +689,7 @@ CREATE VIEW parameters AS
CAST(null AS sql_identifier) AS scope_schema,
CAST(null AS sql_identifier) AS scope_name,
CAST(null AS cardinal_number) AS maximum_cardinality,
CAST(t.oid AS sql_identifier) AS dtd_identifier
CAST(n + 1 AS sql_identifier) AS dtd_identifier
FROM pg_namespace n, pg_proc p, pg_type t, pg_namespace nt, pg_user u,
(select 0 union select 1 union select 2 union select 3 union select 4 union
......@@ -802,8 +817,8 @@ CREATE VIEW routines AS
CAST(null AS sql_identifier) AS udt_name,
CAST(
CASE WHEN nt.nspname = 'pg_catalog'
THEN format_type(t.oid, null)
CASE WHEN t.typelem <> 0 AND t.typlen = -1 THEN 'ARRAY'
WHEN nt.nspname = 'pg_catalog' THEN format_type(t.oid, null)
ELSE 'USER-DEFINED' END AS character_data)
AS data_type,
CAST(null AS cardinal_number) AS character_maximum_length,
......@@ -827,7 +842,7 @@ CREATE VIEW routines AS
CAST(null AS sql_identifier) AS scope_schema,
CAST(null AS sql_identifier) AS scope_name,
CAST(null AS cardinal_number) AS maximum_cardinality,
CAST(t.oid AS sql_identifier) AS dtd_identifier,
CAST(0 AS sql_identifier) AS dtd_identifier,
CAST(CASE WHEN l.lanname = 'sql' THEN 'SQL' ELSE 'EXTERNAL' END AS character_data)
AS routine_body,
......@@ -1364,3 +1379,125 @@ CREATE VIEW views AS
OR has_table_privilege(c.oid, 'TRIGGER') );
GRANT SELECT ON views TO PUBLIC;
-- The following views have dependencies that force them to appear out of order.
/*
* 20.21
* DATA_TYPE_PRIVILEGES view
*/
CREATE VIEW data_type_privileges AS
SELECT CAST(current_database() AS sql_identifier) AS object_catalog,
CAST(x.objschema AS sql_identifier) AS object_schema,
CAST(x.objname AS sql_identifier) AS object_name,
CAST(x.objtype AS character_data) AS object_type,
CAST(x.objdtdid AS sql_identifier) AS dtd_identifier
FROM
(
SELECT table_schema, table_name, 'TABLE'::text, dtd_identifier FROM columns
UNION
SELECT domain_schema, domain_name, 'DOMAIN'::text, dtd_identifier FROM domains
UNION
SELECT specific_schema, specific_name, 'ROUTINE'::text, dtd_identifier FROM parameters
UNION
SELECT specific_schema, specific_name, 'ROUTINE'::text, dtd_identifier FROM routines
) AS x (objschema, objname, objtype, objdtdid);
GRANT SELECT ON data_type_privileges TO PUBLIC;
/*
* 20.27
* ELEMENT_TYPES view
*/
CREATE VIEW element_types AS
SELECT CAST(current_database() AS sql_identifier) AS object_catalog,
CAST(n.nspname AS sql_identifier) AS object_schema,
CAST(x.objname AS sql_identifier) AS object_name,
CAST(x.objtype AS character_data) AS object_type,
CAST(x.objdtdid AS sql_identifier) AS array_type_identifier,
CAST(
CASE WHEN nbt.nspname = 'pg_catalog' THEN format_type(bt.oid, null)
ELSE 'USER-DEFINED' END AS character_data) AS data_type,
CAST(null AS cardinal_number) AS character_maximum_length,
CAST(null AS cardinal_number) AS character_octet_length,
CAST(null AS sql_identifier) AS character_set_catalog,
CAST(null AS sql_identifier) AS character_set_schema,
CAST(null AS sql_identifier) AS character_set_name,
CAST(null AS sql_identifier) AS collation_catalog,
CAST(null AS sql_identifier) AS collation_schema,
CAST(null AS sql_identifier) AS collation_name,
CAST(null AS cardinal_number) AS numeric_precision,
CAST(null AS cardinal_number) AS numeric_precision_radix,
CAST(null AS cardinal_number) AS numeric_scale,
CAST(null AS cardinal_number) AS datetime_precision,
CAST(null AS character_data) AS interval_type,
CAST(null AS character_data) AS interval_precision,
CAST(null AS character_data) AS domain_default, -- XXX maybe a bug in the standard
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(null AS sql_identifier) AS scope_catalog,
CAST(null AS sql_identifier) AS scope_schema,
CAST(null AS sql_identifier) AS scope_name,
CAST(null AS cardinal_number) AS maximum_cardinality,
CAST('a' || x.objdtdid AS sql_identifier) AS dtd_identifier
FROM pg_namespace n, pg_type at, pg_namespace nbt, pg_type bt,
(
/* columns */
SELECT c.relnamespace, c.relname, 'TABLE'::text, a.attnum, a.atttypid
FROM pg_class c, pg_attribute a
WHERE c.oid = a.attrelid
AND c.relkind IN ('r', 'v')
AND attnum > 0 AND NOT attisdropped
UNION
/* domains */
SELECT t.typnamespace, t.typname, 'DOMAIN'::text, 1, t.typbasetype
FROM pg_type t
WHERE t.typtype = 'd'
UNION
/* parameters */
SELECT p.pronamespace, p.proname, 'ROUTINE'::text, pos.n + 1, p.proargtypes[n]
FROM pg_proc p,
(select 0 union 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) AS pos(n)
WHERE p.pronargs > pos.n
UNION
/* result types */
SELECT p.pronamespace, p.proname, 'ROUTINE'::text, 0, p.prorettype
FROM pg_proc p
) AS x (objschema, objname, objtype, objdtdid, objtypeid)
WHERE n.oid = x.objschema
AND at.oid = x.objtypeid
AND (at.typelem <> 0 AND at.typlen = -1)
AND at.typelem = bt.oid
AND nbt.oid = bt.typnamespace
AND (x.objschema, x.objname, x.objtype, x.objtypeid) IN
( SELECT object_schema, object_name, object_type, dtd_identifier
FROM data_type_privileges );
GRANT SELECT ON element_types TO PUBLIC;
Markdown is supported
0% or
You are about to add 0 people to the discussion. Proceed with caution.
Finish editing this message first!
Please register or to comment