diff options
author | Tom Lane <tgl@sss.pgh.pa.us> | 2011-10-14 20:24:50 -0400 |
---|---|---|
committer | Tom Lane <tgl@sss.pgh.pa.us> | 2011-10-14 20:24:50 -0400 |
commit | 0a6209f464ab86de496c0f63190ddc6247c6f6dd (patch) | |
tree | a9b97d1dcb5dffc3efe799d96fac2773aaf36507 /src | |
parent | f655c3f0236ad7b5de3589a6edb633c0120f7dc9 (diff) |
Fix bugs in information_schema.referential_constraints view.
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).
Diffstat (limited to 'src')
-rw-r--r-- | src/backend/catalog/information_schema.sql | 26 |
1 files changed, 15 insertions, 11 deletions
diff --git a/src/backend/catalog/information_schema.sql b/src/backend/catalog/information_schema.sql index a9566d9d3f3..283b3f28a06 100644 --- a/src/backend/catalog/information_schema.sql +++ b/src/backend/catalog/information_schema.sql @@ -1099,17 +1099,21 @@ 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'); + 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'); GRANT SELECT ON referential_constraints TO PUBLIC; |