-<!-- $Header: /cvsroot/pgsql/doc/src/sgml/information_schema.sgml,v 1.1 2003/05/18 20:55:56 petere Exp $ -->
+<!-- $Header: /cvsroot/pgsql/doc/src/sgml/information_schema.sgml,v 1.2 2003/05/25 09:36:09 petere Exp $ -->
<chapter id="information-schema">
<title>The Information Schema</title>
<para>
The view <literal>check_constraints</literal> contains all check
constraints, either defined on a table or on a domain, that are
- owned by the current user.
+ owned by the current user. (The owner of the table or domain is
+ the owner of the constraint.)
</para>
<table>
<para>
The view <literal>columns</literal> contains information about all
table columns (or view columns) in the database. System columns
- (<literal>oid</>, etc.) are not included.
+ (<literal>oid</>, etc.) are not included. Only those columns are
+ shown that the current user has access to (by way of being the
+ owner or having some privilege).
</para>
<table>
<row>
<entry><literal>data_type</literal></entry>
<entry><type>character_data</type></entry>
- <entry>Data type of the column</entry>
+ <entry>
+ Data type of the column, 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). If the column is based on a domain, this column
+ refers to the type underlying the domain (and the domain is
+ identified in <literal>domain_name</literal> and associated
+ columns).
+ </entry>
</row>
<row>
<entry><literal>character_maximum_length</literal></entry>
<entry><type>cardinal_number</type></entry>
<entry>
- If the column has a character or bit string type, the declared
- maximum length; null for all other data types or if no maximum
- length was declared.
+ If <literal>data_type</literal> identifies a character or bit
+ string type, the declared maximum length; null for all other
+ data types or if no maximum length was declared.
</entry>
</row>
<entry><literal>character_octet_length</literal></entry>
<entry><type>cardinal_number</type></entry>
<entry>
- If the column has a character type, the maximum possible length
- in octets (bytes) of a datum (this should not be of concern to
- PostgreSQL users); null for all other data types.
+ If <literal>data_type</literal> identifies a character type,
+ the maximum possible length in octets (bytes) of a datum (this
+ should not be of concern to PostgreSQL users); null for all
+ other data types.
</entry>
</row>
<entry><literal>numeric_precision</literal></entry>
<entry><type>cardinal_number</type></entry>
<entry>
- If the column has a numeric type, this column contains the
- (declared or implicit) precision of the type for this column.
- The precision indicates the number of significant digits. It
- may be expressed in decimal (base 10) or binary (base 2) terms,
- as specified in the column
+ If <literal>data_type</literal> identifies a numeric type, this
+ column contains the (declared or implicit) precision of the
+ type for this column. The precision indicates the number of
+ significant digits. It may be expressed in decimal (base 10)
+ or binary (base 2) terms, as specified in the column
<literal>numeric_precision_radix</literal>. For all other data
types, this column is null.
</entry>
<entry><literal>numeric_precision_radix</literal></entry>
<entry><type>cardinal_number</type></entry>
<entry>
- If the column has a numeric type, this column indicates in
- which base the values in the columns
+ If <literal>data_type</literal> identifies a numeric type, this
+ column indicates in which base the values in the columns
<literal>numeric_precision</literal> and
<literal>numeric_scale</literal> are expressed. The value is
either 2 or 10. For all other data types, this column is null.
<entry><literal>numeric_scale</literal></entry>
<entry><type>cardinal_number</type></entry>
<entry>
- If the column has an exact numeric type, this column contains
- the (declared or implicit) scale of the type for this column.
- The scale indicates the number of significant digits to the
- right of the decimal point. It may be expressed in decimal
- (base 10) or binary (base 2) terms, as specified in the column
+ If <literal>data_type</literal> identifies an exact numeric
+ type, this column contains the (declared or implicit) scale of
+ the type for this column. The scale indicates the number of
+ significant digits to the right of the decimal point. It may
+ be expressed in decimal (base 10) or binary (base 2) terms, as
+ specified in the column
<literal>numeric_precision_radix</literal>. For all other data
types, this column is null.
</entry>
<entry><literal>datetime_precision</literal></entry>
<entry><type>cardinal_number</type></entry>
<entry>
- If the column has a date, time, or interval type, the declared
- precision; null for all other data types or if no precision was
- declared.
+ If <literal>data_type</literal> identifies a date, time, or
+ interval type, the declared precision; null for all other data
+ types or if no precision was declared.
</entry>
</row>
<entry><literal>udt_catalog</literal></entry>
<entry><type>sql_identifier</type></entry>
<entry>
- Name of the database that the column data type is defined in
- (always the current database), null if the column has a domain
- type.
+ 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>
<entry><literal>udt_schema</literal></entry>
<entry><type>sql_identifier</type></entry>
<entry>
- Name of the schema that the column data type is defined in,
- null if the column has a domain type.
+ 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, null if the column has a domain type.</entry>
+ <entry>
+ Name of the column data type (the underlying type of the
+ domain, if applicable)
+ </entry>
</row>
<row>
<row>
<entry><literal>dtd_identifier</literal></entry>
<entry><type>sql_identifier</type></entry>
- <entry>Applies to a feature not available in PostgreSQL</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.)
+ </entry>
</row>
<row>
</tbody>
</tgroup>
</table>
+
+ <para>
+ Since data types can be defined in a variety of ways in SQL, and
+ PostgreSQL contains additional ways to define data types, their
+ representation in the information schema can be somewhat difficult.
+ The column <literal>data_type</literal> is supposed to identify the
+ underlying built-in type of the column. In PostgreSQL, this means
+ that the type is defined in the system catalog schema
+ <literal>pg_catalog</literal>. This column may be useful if the
+ application can handle the well-known built-in types specially (for
+ example, format the numeric types differently or use the data in
+ the precision columns). The columns <literal>udt_name</literal>,
+ <literal>udt_schema</literal>, and <literal>udt_catalog</literal>
+ always identify the underlying data type of the column, even if the
+ column is based on a domain. (Since PostgreSQL treats built-in
+ types like user-defined types, built-in types appear here as well.
+ This is an extension of the SQL standard.) These columns should be
+ used if an application wants to process data differently according
+ to the type, because in that case it wouldn't matter if the column
+ is really based on a domain. If the column is based on a domain,
+ the identity of the domain is stored in the columns
+ <literal>domain_name</literal>, <literal>domain_schema</literal>,
+ 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>.
+ </para>
+ </sect1>
+
+ <sect1 id="infoschema-constraint-table-usage">
+ <title><literal>constraint_table_usage</literal></title>
+
+ <para>
+ The view <literal>constraint_table_usage</literal> identifies all
+ tables in the current database that are used by some constraint and
+ are owned by the current user. (This is different from the view
+ <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.
+ </para>
+
+ <table>
+ <title><literal>constraint_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>table_catalog</literal></entry>
+ <entry><type>sql_identifier</type></entry>
+ <entry>
+ Name of the database that contains the table 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 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 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-domain-constraints">
<para>
The view <literal>domain_constraints</literal> contains all
- constraints belonging to domains.
+ constraints belonging to domains owned by the current user.
</para>
<table>
<row>
<entry><literal>unique_constraint_catalog</literal></entry>
<entry><literal>sql_identifier</literal></entry>
- <entry>Not yet implemented</entry>
+ <entry>
+ Name of the database that contains the unique or primary key
+ constraint that the foreign key constraint references (always
+ the current database)
+ </entry>
</row>
<row>
<entry><literal>unique_constraint_schema</literal></entry>
<entry><literal>sql_identifier</literal></entry>
- <entry>Not yet implemented</entry>
+ <entry>
+ Name of the schema that contains the unique or primary key
+ constraint that the foreign key constraint references
+ </entry>
</row>
<row>
<entry><literal>unique_constraint_name</literal></entry>
<entry><literal>sql_identifier</literal></entry>
- <entry>Not yet implemented</entry>
+ <entry>
+ Name of the unique or primary key constraint that the foreign
+ key constraint references
+ </entry>
</row>
<row>
<entry><literal>match_option</literal></entry>
<entry><literal>character_data</literal></entry>
<entry>
- Match option of the referential constraint:
+ Match option of the foreign key constraint:
<literal>FULL</literal>, <literal>PARTIAL</literal>, or
<literal>NONE</literal>.
</entry>
<entry><literal>update_rule</literal></entry>
<entry><literal>character_data</literal></entry>
<entry>
- Update rule of the referential constraint:
+ Update rule of the foreign key constraint:
<literal>CASCADE</literal>, <literal>SET NULL</literal>,
<literal>SET DEFAULT</literal>, <literal>RESTRICT</literal>,or
<literal>NO ACTION</literal>.
<entry><literal>delete_rule</literal></entry>
<entry><literal>character_data</literal></entry>
<entry>
- Delete rule of the referential constraint:
+ Delete rule of the foreign key constraint:
<literal>CASCADE</literal>, <literal>SET NULL</literal>,
<literal>SET DEFAULT</literal>, <literal>RESTRICT</literal>,or
<literal>NO ACTION</literal>.
<para>
The view <literal>schemata</literal> contains all schemas in the
- current database.
+ current database that are owned by the current user.
</para>
<table>
<para>
The view <literal>table_constraints</literal> contains all
- constraints belonging to tables.
+ constraints belonging to tables owned by the current user.
</para>
<table>
<para>
The view <literal>tables</literal> contains all tables and views
- defined in the current database.
+ defined in the current database. Only those tables and views are
+ shown that the current user has access to (by way of being the
+ owner or having some privilege).
</para>
<table>
<para>
The view <literal>views</literal> contains all views defined in the
- current database.
+ current database. Only those views are shown that the current user
+ has access to (by way of being the owner or having some privilege).
</para>
<table>
*
* Copyright 2002, PostgreSQL Global Development Group
*
- * $Id: information_schema.sql,v 1.5 2003/05/18 20:55:57 petere Exp $
+ * $Id: information_schema.sql,v 1.6 2003/05/25 09:36:09 petere Exp $
*/
CAST(rs.nspname AS sql_identifier) AS constraint_schema,
CAST(con.conname AS sql_identifier) AS constraint_name,
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),
+ 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),
pg_user u
WHERE rs.oid = con.connamespace
- AND u.usesysid IN (c.relowner, t.typowner)
+ AND u.usesysid = coalesce(c.relowner, t.typowner)
AND u.usename = current_user
AND con.contype = 'c';
CASE WHEN u.usename = current_user THEN a.adsrc ELSE null END
AS character_data)
AS column_default,
- CAST(CASE WHEN a.attnotnull THEN 'NO' ELSE 'YES' END
+ CAST(CASE WHEN a.attnotnull OR (t.typtype = 'd' AND t.typnotnull) THEN 'NO' ELSE 'YES' END
AS character_data)
AS is_nullable,
- CAST(format_type(a.atttypid, null) AS character_data)
+
+ CAST(
+ CASE WHEN t.typtype = 'd' THEN
+ CASE 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)
+ ELSE 'USER-DEFINED' END
+ END
+ AS character_data)
AS data_type,
CAST(
- CASE WHEN a.atttypid IN (25, 1042, 1043, 1560, 1562) AND a.atttypmod <> -1
- THEN a.atttypmod - 4
- ELSE null END
+ CASE WHEN t.typtype = 'd' THEN
+ CASE WHEN t.typbasetype IN (25, 1042, 1043, 1560, 1562) AND t.typtypmod <> -1
+ THEN t.typtypmod - 4
+ ELSE null END
+ ELSE
+ CASE WHEN a.atttypid IN (25, 1042, 1043, 1560, 1562) AND a.atttypmod <> -1
+ THEN a.atttypmod - 4
+ ELSE null END
+ END
AS cardinal_number)
AS character_maximum_length,
CAST(
- CASE WHEN a.atttypid IN (25, 1042, 1043) THEN 2^30 ELSE null END
+ CASE WHEN t.typtype = 'd' THEN
+ CASE WHEN t.typbasetype IN (25, 1042, 1043) THEN 2^30 ELSE null END
+ ELSE
+ CASE WHEN a.atttypid IN (25, 1042, 1043) THEN 2^30 ELSE null END
+ END
AS cardinal_number)
AS character_octet_length,
CAST(
- CASE a.atttypid
+ CASE (CASE WHEN t.typtype = 'd' THEN t.typbasetype ELSE a.atttypid END)
WHEN 21 /*int2*/ THEN 16
WHEN 23 /*int4*/ THEN 32
WHEN 20 /*int8*/ THEN 64
- WHEN 1700 /*numeric*/ THEN ((a.atttypmod - 4) >> 16) & 65535
+ WHEN 1700 /*numeric*/ THEN ((CASE WHEN t.typtype = 'd' THEN t.typtypmod ELSE a.atttypmod END - 4) >> 16) & 65535
WHEN 700 /*float4*/ THEN 24 /*FLT_MANT_DIG*/
WHEN 701 /*float8*/ THEN 53 /*DBL_MANT_DIG*/
ELSE null END
AS numeric_precision,
CAST(
- CASE WHEN a.atttypid IN (21, 23, 20, 700, 701) THEN 2
- WHEN a.atttypid IN (1700) THEN 10
- ELSE null END
+ CASE WHEN t.typtype = 'd' THEN
+ CASE WHEN t.typbasetype IN (21, 23, 20, 700, 701) THEN 2
+ WHEN t.typbasetype IN (1700) THEN 10
+ ELSE null END
+ ELSE
+ CASE WHEN a.atttypid IN (21, 23, 20, 700, 701) THEN 2
+ WHEN a.atttypid IN (1700) THEN 10
+ ELSE null END
+ END
AS cardinal_number)
AS numeric_precision_radix,
CAST(
- CASE WHEN a.atttypid IN (21, 23, 20) THEN 0
- WHEN a.atttypid IN (1700) THEN (a.atttypmod - 4) & 65535
- ELSE null END
+ CASE WHEN t.typtype = 'd' THEN
+ CASE WHEN t.typbasetype IN (21, 23, 20) THEN 0
+ WHEN t.typbasetype IN (1700) THEN (t.typtypmod - 4) & 65535
+ ELSE null END
+ ELSE
+ CASE WHEN a.atttypid IN (21, 23, 20) THEN 0
+ WHEN a.atttypid IN (1700) THEN (a.atttypmod - 4) & 65535
+ ELSE null END
+ END
AS cardinal_number)
AS numeric_scale,
CAST(
- CASE WHEN a.atttypid IN (1083, 1114, 1184, 1266)
- THEN (CASE WHEN a.atttypmod <> -1 THEN a.atttypmod ELSE null END)
- WHEN a.atttypid IN (1186)
- THEN (CASE WHEN a.atttypmod <> -1 THEN a.atttypmod & 65535 ELSE null END)
- ELSE null END
+ CASE WHEN t.typtype = 'd' THEN
+ CASE WHEN t.typbasetype IN (1083, 1114, 1184, 1266)
+ THEN (CASE WHEN t.typtypmod <> -1 THEN t.typtypmod ELSE null END)
+ WHEN t.typbasetype IN (1186)
+ THEN (CASE WHEN t.typtypmod <> -1 THEN t.typtypmod & 65535 ELSE null END)
+ ELSE null END
+ ELSE
+ CASE WHEN a.atttypid IN (1083, 1114, 1184, 1266)
+ THEN (CASE WHEN a.atttypmod <> -1 THEN a.atttypmod ELSE null END)
+ WHEN a.atttypid IN (1186)
+ THEN (CASE WHEN a.atttypmod <> -1 THEN a.atttypmod & 65535 ELSE null END)
+ ELSE null END
+ END
AS cardinal_number)
AS datetime_precision,
CAST(CASE WHEN t.typtype = 'd' THEN t.typname ELSE null END
AS sql_identifier) AS domain_name,
- CAST(CASE WHEN t.typtype <> 'd' THEN current_database() ELSE null END
- AS sql_identifier) AS udt_catalog,
- CAST(CASE WHEN t.typtype <> 'd' THEN nt.nspname ELSE null END
- AS sql_identifier) AS udt_schema,
- CAST(CASE WHEN t.typtype <> 'd' THEN t.typname ELSE null END
- AS sql_identifier) AS udt_name,
+ 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(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(null AS sql_identifier) AS dtd_identifier,
+ CAST(CAST(t.oid AS varchar) 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,
- pg_class c, pg_namespace nc, pg_type t, pg_namespace nt, pg_user u
+ FROM (pg_attribute LEFT JOIN pg_attrdef ON attrelid = adrelid AND attnum = adnum) AS 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 = c.relowner
- AND nc.oid = c.relnamespace
- AND nt.oid = t.typnamespace
- AND u.usename = current_user
+ WHERE a.attrelid = c.oid
+ AND a.atttypid = t.oid
+ AND u.usesysid = c.relowner
+ AND nc.oid = c.relnamespace
- AND a.attnum > 0 AND NOT a.attisdropped AND c.relkind in ('r', 'v');
+ AND a.attnum > 0 AND NOT a.attisdropped AND c.relkind in ('r', 'v')
+
+ AND (u.usename = current_user
+ 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') );
GRANT SELECT ON columns TO PUBLIC;
+/*
+ * 20.19
+ * 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,
+ CAST(tblname AS sql_identifier) AS table_name,
+ CAST(colname AS sql_identifier) AS column_name,
+ CAST(current_database() AS sql_identifier) AS constraint_catalog,
+ CAST(cstrschema AS sql_identifier) AS constraint_schema,
+ CAST(cstrname AS sql_identifier) AS constraint_name
+
+ FROM (
+ 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
+ AND r.oid = a.attrelid
+ AND d.refclassid = (SELECT oid FROM pg_class WHERE relname = 'pg_class')
+ AND d.refobjid = r.oid
+ AND d.refobjsubid = a.attnum
+ AND d.classid = (SELECT oid FROM pg_class WHERE relname = 'pg_constraint')
+ AND d.objid = c.oid
+ AND c.connamespace = nc.oid
+ AND c.contype = 'c'
+ ) AS x (tblschema, tblname, tblowner, colname, cstrschema, cstrname),
+ pg_user u
+
+ WHERE x.tblowner = u.usesysid AND u.usename = current_user;
+
+GRANT SELECT ON constraint_column_usage TO PUBLIC;
+
+
+/*
+ * 20.20
+ * CONSTRAINT_TABLE_USAGE view
+ */
+
+CREATE VIEW constraint_table_usage AS
+ SELECT 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(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
+
+ FROM pg_constraint c, pg_namespace nc,
+ pg_class r, pg_namespace nr,
+ pg_user u
+
+ 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.relowner = u.usesysid AND u.usename = current_user;
+
+GRANT SELECT ON constraint_table_usage TO PUBLIC;
+
+
/*
* 20.24
* DOMAIN_CONSTRAINTS view
CREATE VIEW domains AS
SELECT CAST(current_database() AS sql_identifier) AS domain_catalog,
- CAST(rs.nspname AS sql_identifier) AS domain_schema,
+ CAST(nt.nspname AS sql_identifier) AS domain_schema,
CAST(t.typname AS sql_identifier) AS domain_name,
- CAST(format_type(t.typbasetype, null) AS character_data)
+
+ CAST(
+ CASE WHEN nbt.nspname = 'pg_catalog'
+ THEN format_type(t.typbasetype, null)
+ ELSE 'USER-DEFINED' END
+ AS character_data)
AS data_type,
CAST(
CASE WHEN t.typbasetype IN (25, 1042, 1043) THEN 2^30 ELSE null END
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 character_data) AS interval_type, -- XXX
CAST(null AS character_data) AS interval_precision, -- XXX
- CAST(typdefault AS character_data) AS domain_default,
+ CAST(t.typdefault AS character_data) AS domain_default,
- CAST(CASE WHEN t.typbasetype = 0 THEN current_database() ELSE null END
- AS sql_identifier) AS udt_catalog,
- CAST(CASE WHEN t.typbasetype = 0 THEN rs.nspname ELSE null END
- AS sql_identifier) AS udt_schema,
- CAST(CASE WHEN t.typbasetype = 0 THEN t.typname ELSE null END
- AS sql_identifier) AS udt_name,
+ 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(null AS sql_identifier) AS dtd_identifier
-
- FROM pg_namespace rs,
- pg_type t,
- pg_user u
+ CAST(CAST(t.oid AS varchar) AS sql_identifier) AS dtd_identifier
- WHERE rs.oid = t.typnamespace
- AND t.typtype = 'd'
- AND t.typowner = u.usesysid
- AND (u.usename = current_user
- OR EXISTS (SELECT 1
- FROM pg_user AS u2
- WHERE rs.nspowner = u2.usesysid
- AND u2.usename = current_user)
- OR EXISTS (SELECT 1
- FROM pg_user AS u3,
- pg_attribute AS a3,
- pg_class AS c3
- WHERE u3.usesysid = c3.relowner
- AND a3.attrelid = c3.oid
- AND a3.atttypid = t.oid));
+ FROM pg_type t, pg_namespace nt,
+ pg_type bt, pg_namespace nbt
+ WHERE t.typnamespace = nt.oid
+ AND t.typbasetype = bt.oid
+ AND bt.typnamespace = nbt.oid
+ AND t.typtype = 'd';
GRANT SELECT ON domains TO PUBLIC;
CAST(ncon.nspname AS sql_identifier) AS constraint_schema,
CAST(con.conname AS sql_identifier) AS constraint_name,
CAST(current_database() AS sql_identifier) AS unique_constraint_catalog,
- CAST(null AS sql_identifier) AS unique_constraint_schema, -- XXX
- CAST(null AS sql_identifier) AS unique_constraint_name, -- XXX
+ CAST(npkc.nspname AS sql_identifier) AS unique_constraint_schema,
+ CAST(pkc.conname AS sql_identifier) AS unique_constraint_name,
CAST(
CASE con.confmatchtype WHEN 'f' THEN 'FULL'
FROM pg_namespace ncon,
pg_constraint con,
- pg_class r,
+ pg_class c,
+ pg_constraint pkc,
+ pg_namespace npkc,
pg_user u
WHERE ncon.oid = con.connamespace
- AND con.conrelid = r.oid AND r.relowner = u.usesysid
+ AND con.conrelid = c.oid
+ AND con.confkey = pkc.conkey
+ AND pkc.connamespace = npkc.oid
+ AND c.relowner = u.usesysid
AND u.usename = current_user;
GRANT SELECT ON referential_constraints TO PUBLIC;
FROM pg_namespace nc, pg_class c, pg_user u
WHERE c.relnamespace = nc.oid AND u.usesysid = c.relowner
+ AND c.relkind IN ('r', 'v')
AND (u.usename = current_user
- OR EXISTS(SELECT 1 FROM information_schema.table_privileges tp
- WHERE tp.table_schema = nc.nspname
- AND tp.table_name = c.relname
- AND tp.grantee = current_user))
-
- AND c.relkind IN ('r', 'v');
+ 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') );
GRANT SELECT ON tables TO PUBLIC;
FROM pg_namespace nc, pg_class c, pg_user u
WHERE c.relnamespace = nc.oid AND u.usesysid = c.relowner
+ AND c.relkind = 'v'
AND (u.usename = current_user
- OR EXISTS(SELECT 1 FROM information_schema.table_privileges tp
- WHERE tp.table_schema = nc.nspname
- AND tp.table_name = c.relname
- AND tp.grantee = current_user))
-
- AND c.relkind = 'v';
+ 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') );
GRANT SELECT ON views TO PUBLIC;