Обсуждение: information_schema.constraint_column_usage shows wrong table name

Поиск
Список
Период
Сортировка

information_schema.constraint_column_usage shows wrong table name

От
Alex Zeng
Дата:
Hi,

When creating a constraint from table A to table B, the table name and column name in information_schema.constraint_column_usage  shows table B. That makes impossible to check whether a constraint exists as we can have a constraint from table C to B and they will have same value in information_schema.constraint_column_usage.

Should we make the table_name and column_name as A's name?

=# create table item(id integer, item_name character VARYING(64),cat_id integer);
CREATE TABLE
=# create table catagory(id integer, cat_name character VARYING(64),CONSTRAINT catagory_pkey PRIMARY KEY (id) );
CREATE TABLE
=# alter table item add constraint fk_cat_id FOREIGN KEY (cat_id) REFERENCES catagory(id);
ALTER TABLE
=# select * from information_schema.constraint_column_usage where constraint_name='fk_cat_id';
 table_catalog | table_schema | table_name | column_name | constraint_catalog | constraint_schema | constraint_name
---------------+--------------+------------+-------------+--------------------+-------------------+-----------------
 vretrieve     | public       | catagory   | id          | vretrieve          | public            | fk_cat_id
(1 row)


This email with any attachments is confidential and may be subject to legal privilege. If it is not intended for you please reply immediately, destroy it and do not copy, disclose or use it in any way.

Re: information_schema.constraint_column_usage shows wrong table name

От
"David G. Johnston"
Дата:
On Mon, Aug 9, 2021 at 8:12 PM Alex Zeng <Alex.Zeng@datam.co.nz> wrote:
When creating a constraint from table A to table B, the table name and column name in information_schema.constraint_column_usage  shows table B. That makes impossible to check whether a constraint exists as we can have a constraint from table C to B and they will have same value in information_schema.constraint_column_usage.

Going from memory here but I believe what you are seeing is a consequence of not following the SQL standard for naming things and then using an SQL standard view to inspect the meta-data.  This is one of the few cases where the flexibility we provide above-and-beyond the SQL standard renders using one of its features problematic.  You will either need to standardize your naming or use the pg_catalog.

David J.

Re: information_schema.constraint_column_usage shows wrong table name

От
Tom Lane
Дата:
Alex Zeng <Alex.Zeng@datam.co.nz> writes:
> When creating a constraint from table A to table B, the table name and column name in
information_schema.constraint_column_usage shows table B. That makes impossible to check whether a constraint exists as
wecan have a constraint from table C to B and they will have same value in information_schema.constraint_column_usage. 

The SQL standard says the purpose of this view is to

    Identify the columns used by referential constraints, unique
    constraints, check constraints, and assertions defined in this catalog
    and owned by a given user or role.

so I think the view is showing the column name it is supposed to,
ie the referenced column name not the referencing column name.
The key_column_usage view might help you with the other thing.

            regards, tom lane