From: Peter Eisentraut Date: Sun, 25 May 2003 09:36:09 +0000 (+0000) Subject: Information schema improvements X-Git-Tag: REL9_0_0~15261 X-Git-Url: http://git.osdn.net/view?a=commitdiff_plain;h=297c1658ed35dc0ac4a13c190f29cc5e2ad49a0b;p=pg-rex%2Fsyncrep.git Information schema improvements --- diff --git a/doc/src/sgml/information_schema.sgml b/doc/src/sgml/information_schema.sgml index dd58a9e330..f866cf7278 100644 --- a/doc/src/sgml/information_schema.sgml +++ b/doc/src/sgml/information_schema.sgml @@ -1,4 +1,4 @@ - + The Information Schema @@ -148,7 +148,8 @@ The view check_constraints 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.) @@ -266,7 +267,9 @@ The view columns contains information about all table columns (or view columns) in the database. System columns - (oid, etc.) are not included. + (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).
@@ -335,16 +338,24 @@ data_type character_data - Data type of the column + + Data type of the column, if it is a built-in type, else + USER-DEFINED (in that case, the type is + identified in udt_name 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 domain_name and associated + columns). + character_maximum_length cardinal_number - 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 data_type identifies a character or bit + string type, the declared maximum length; null for all other + data types or if no maximum length was declared. @@ -352,9 +363,10 @@ character_octet_lengthcardinal_number - 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 data_type 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. @@ -362,11 +374,11 @@ numeric_precisioncardinal_number - 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 data_type 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 numeric_precision_radix. For all other data types, this column is null. @@ -376,8 +388,8 @@ numeric_precision_radixcardinal_number - If the column has a numeric type, this column indicates in - which base the values in the columns + If data_type identifies a numeric type, this + column indicates in which base the values in the columns numeric_precision and numeric_scale are expressed. The value is either 2 or 10. For all other data types, this column is null. @@ -388,11 +400,12 @@ numeric_scale cardinal_number - 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 data_type 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 numeric_precision_radix. For all other data types, this column is null. @@ -402,9 +415,9 @@ datetime_precision cardinal_number - 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 data_type identifies a date, time, or + interval type, the declared precision; null for all other data + types or if no precision was declared. @@ -485,9 +498,9 @@ udt_catalog sql_identifier - 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) @@ -495,15 +508,18 @@ udt_schema sql_identifier - 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 udt_name sql_identifier - Name of the column data type, null if the column has a domain type. + + Name of the column data type (the underlying type of the + domain, if applicable) + @@ -533,7 +549,11 @@ dtd_identifier sql_identifier - Applies to a feature not available in PostgreSQL + + 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.) + @@ -544,6 +564,109 @@
+ + + 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 data_type 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 + pg_catalog. 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 udt_name, + udt_schema, and udt_catalog + 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 + domain_name, domain_schema, + and domain_catalog. If you want to pair up + columns with their associated data types and treat domains as + separate types, you could write coalesce(domain_name, + udt_name), etc. Finally, if you want to check whether + two columns have the same type, use + dtd_identifier. + + + + + <literal>constraint_table_usage</literal> + + + The view constraint_table_usage 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 + table_constraints, 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. + + + + <literal>constraint_table_usage</literal> Columns + + + + + Name + Data Type + Description + + + + + + table_catalog + sql_identifier + + Name of the database that contains the table that is used by + some constraint (always the current database) + + + + + table_schema + sql_identifier + + Name of the schema that contains the table that is used by some + constraint + + + + + table_name + sql_identifier + Name of the table that is used by some constraint + + + + constraint_catalog + sql_identifier + Name of the database that contains the constraint (always the current database) + + + + constraint_schema + sql_identifier + Name of the schema that contains the constraint + + + + constraint_name + sql_identifier + Name of the constraint + + + +
@@ -551,7 +674,7 @@ The view domain_constraints contains all - constraints belonging to domains. + constraints belonging to domains owned by the current user. @@ -883,26 +1006,36 @@ unique_constraint_catalog sql_identifier - Not yet implemented + + Name of the database that contains the unique or primary key + constraint that the foreign key constraint references (always + the current database) + unique_constraint_schema sql_identifier - Not yet implemented + + Name of the schema that contains the unique or primary key + constraint that the foreign key constraint references + unique_constraint_name sql_identifier - Not yet implemented + + Name of the unique or primary key constraint that the foreign + key constraint references + match_option character_data - Match option of the referential constraint: + Match option of the foreign key constraint: FULL, PARTIAL, or NONE. @@ -912,7 +1045,7 @@ update_rule character_data - Update rule of the referential constraint: + Update rule of the foreign key constraint: CASCADE, SET NULL, SET DEFAULT, RESTRICT,or NO ACTION. @@ -923,7 +1056,7 @@ delete_rule character_data - Delete rule of the referential constraint: + Delete rule of the foreign key constraint: CASCADE, SET NULL, SET DEFAULT, RESTRICT,or NO ACTION. @@ -939,7 +1072,7 @@ The view schemata contains all schemas in the - current database. + current database that are owned by the current user.
@@ -1420,7 +1553,7 @@ The view table_constraints contains all - constraints belonging to tables. + constraints belonging to tables owned by the current user.
@@ -1583,7 +1716,9 @@ The view tables 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).
@@ -1667,7 +1802,8 @@ The view views 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).
diff --git a/src/backend/catalog/information_schema.sql b/src/backend/catalog/information_schema.sql index 0fb1abe471..6dc3ac7b29 100644 --- a/src/backend/catalog/information_schema.sql +++ b/src/backend/catalog/information_schema.sql @@ -4,7 +4,7 @@ * * 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 $ */ @@ -76,12 +76,13 @@ CREATE VIEW check_constraints AS 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'; @@ -150,30 +151,51 @@ CREATE VIEW columns AS 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 @@ -181,25 +203,45 @@ CREATE VIEW columns AS 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, @@ -221,37 +263,106 @@ CREATE VIEW columns AS 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 */ @@ -284,9 +395,14 @@ GRANT SELECT ON domain_constraints TO PUBLIC; 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( @@ -300,6 +416,7 @@ CREATE VIEW domains AS 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, @@ -346,42 +463,26 @@ CREATE VIEW domains AS 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; @@ -396,8 +497,8 @@ CREATE VIEW referential_constraints AS 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' @@ -423,11 +524,16 @@ CREATE VIEW referential_constraints AS 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; @@ -714,13 +820,15 @@ CREATE VIEW tables AS 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; @@ -777,12 +885,14 @@ CREATE VIEW views AS 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;