Skip to content

Commit

Permalink
Fix bugs in information_schema.referential_constraints view.
Browse files Browse the repository at this point in the history
This view was being insufficiently careful about matching the FK constraint
to the depended-on primary or unique key constraint.  That could result in
failure to show an FK constraint at all, or showing it multiple times, or
claiming that it depended on a different constraint than the one it really
does.  Fix by joining via pg_depend to ensure that we find only the correct
dependency.

Back-patch, but don't bump catversion because we can't force initdb in back
branches.  The next minor-version release notes should explain that if you
need to fix this in an existing installation, you can drop the
information_schema schema then re-create it by sourcing
$SHAREDIR/information_schema.sql in each database (as a superuser of
course).
  • Loading branch information
tglsfdc committed Oct 15, 2011
1 parent e6858e6 commit d26e1eb
Showing 1 changed file with 18 additions and 14 deletions.
32 changes: 18 additions & 14 deletions src/backend/catalog/information_schema.sql
Original file line number Diff line number Diff line change
Expand Up @@ -1176,20 +1176,24 @@ CREATE VIEW referential_constraints AS

FROM (pg_namespace ncon
INNER JOIN pg_constraint con ON ncon.oid = con.connamespace
INNER JOIN pg_class c ON con.conrelid = c.oid)
LEFT JOIN
(pg_constraint pkc
INNER JOIN pg_namespace npkc ON pkc.connamespace = npkc.oid)
ON con.confrelid = pkc.conrelid
AND _pg_keysequal(con.confkey, pkc.conkey)

WHERE c.relkind = 'r'
AND con.contype = 'f'
AND (pkc.contype IN ('p', 'u') OR pkc.contype IS NULL)
AND (pg_has_role(c.relowner, 'USAGE')
-- SELECT privilege omitted, per SQL standard
OR has_table_privilege(c.oid, 'INSERT, UPDATE, DELETE, TRUNCATE, REFERENCES, TRIGGER')
OR has_any_column_privilege(c.oid, 'INSERT, UPDATE, REFERENCES') );
INNER JOIN pg_class c ON con.conrelid = c.oid AND con.contype = 'f')
LEFT JOIN pg_depend d1 -- find constraint's dependency on an index
ON d1.objid = con.oid AND d1.classid = 'pg_constraint'::regclass
AND d1.refclassid = 'pg_class'::regclass AND d1.refobjsubid = 0
LEFT JOIN pg_depend d2 -- find pkey/unique constraint for that index
ON d2.refclassid = 'pg_constraint'::regclass
AND d2.classid = 'pg_class'::regclass
AND d2.objid = d1.refobjid AND d2.objsubid = 0
AND d2.deptype = 'i'
LEFT JOIN pg_constraint pkc ON pkc.oid = d2.refobjid
AND pkc.contype IN ('p', 'u')
AND pkc.conrelid = con.confrelid
LEFT JOIN pg_namespace npkc ON pkc.connamespace = npkc.oid

WHERE pg_has_role(c.relowner, 'USAGE')
-- SELECT privilege omitted, per SQL standard
OR has_table_privilege(c.oid, 'INSERT, UPDATE, DELETE, TRUNCATE, REFERENCES, TRIGGER')
OR has_any_column_privilege(c.oid, 'INSERT, UPDATE, REFERENCES') ;

GRANT SELECT ON referential_constraints TO PUBLIC;

Expand Down

0 comments on commit d26e1eb

Please sign in to comment.