REFERENTIAL_CONSTRAINTS view

This Information Schema view displays a row for each FOREIGN KEY constraint that is defined for tables in the specified (or current) database.

FOREIGN KEY constraints are used to enforce referential integrity. For more information, see Constraints and Referential Integrity Constraints.

To return information about other constraint types (as well as FOREIGN KEY constraints), query the TABLE_CONSTRAINTS view.

See also:

TABLE_CONSTRAINTS view

Columns

Column Name

Data Type

Description

CONSTRAINT_CATALOG

TEXT

Database that the constraint belongs to

CONSTRAINT_SCHEMA

TEXT

Schema that the constraint belongs to

CONSTRAINT_NAME

TEXT

Name of the constraint

UNIQUE_CONSTRAINT_CATALOG

TEXT

Database of the unique constraint referenced by the current constraint

UNIQUE_CONSTRAINT_SCHEMA

TEXT

Schema of the unique constraint referenced by the current constraint

UNIQUE_CONSTRAINT_NAME

TEXT

Name of the unique constraint referenced by the current constraint

MATCH_OPTION

TEXT

Match option for the constraint

UPDATE_RULE

TEXT

Update Rule for the current constraint

DELETE_RULE

TEXT

Delete Rule for the current constraint

COMMENT

TEXT

Comment for this constraint

CREATED

TIMESTAMP_LTZ

Creation time of the constraint

LAST_ALTERED

TIMESTAMP_LTZ

Date and time the object was last altered by a DML, DDL, or background metadata operation. See Usage Notes.

Usage notes

  • The view only displays objects for which the current role for the session has been granted access privileges.

  • The LAST_ALTERED column is updated when the following operations are performed on an object:

    • DDL operations.

    • DML operations (for tables only). This column is updated even when no rows are affected by the DML statement.

    • Background maintenance operations on metadata performed by Snowflake.

Examples

Return information about all of the FOREIGN KEY constraints in the current database.

SELECT * FROM INFORMATION_SCHEMA.REFERENTIAL_CONSTRAINTS;
Copy
+--------------------+-------------------+-----------------------------------------------------+---------------------------+--------------------------+-----------------------------------------------------+--------------+-------------+-------------+---------+-------------------------------+-------------------------------+
| CONSTRAINT_CATALOG | CONSTRAINT_SCHEMA | CONSTRAINT_NAME                                     | UNIQUE_CONSTRAINT_CATALOG | UNIQUE_CONSTRAINT_SCHEMA | UNIQUE_CONSTRAINT_NAME                              | MATCH_OPTION | UPDATE_RULE | DELETE_RULE | COMMENT | CREATED                       | LAST_ALTERED                  |
|--------------------+-------------------+-----------------------------------------------------+---------------------------+--------------------------+-----------------------------------------------------+--------------+-------------+-------------+---------+-------------------------------+-------------------------------|
| HTABLES_DB         | HTABLES_SCHEMA    | SYS_CONSTRAINT_51118aaf-1ee6-4548-bc9a-f87e65d92528 | HTABLES_DB                | HTABLES_SCHEMA           | SYS_CONSTRAINT_aad16788-491a-4e68-b0e3-30d48a33a1c1 | FULL         | NO ACTION   | NO ACTION   | NULL    | 2024-09-19 13:51:37.355 -0700 | 2024-09-19 13:51:37.608 -0700 |
| HTABLES_DB         | HTABLES_SCHEMA    | SYS_CONSTRAINT_c97bfe9b-6098-4b8a-b796-e341071db72a | HTABLES_DB                | HTABLES_SCHEMA           | SYS_CONSTRAINT_0bd41d0f-11f7-4366-82a3-f03f31fcce7e | FULL         | NO ACTION   | NO ACTION   | NULL    | 2024-05-28 18:21:43.899 -0700 | 2024-05-28 18:21:44.268 -0700 |
+--------------------+-------------------+-----------------------------------------------------+---------------------------+--------------------------+-----------------------------------------------------+--------------+-------------+-------------+---------+-------------------------------+-------------------------------+

Join this view to the TABLE_CONSTRAINTS view to get the names of referencing tables that have FOREIGN KEY constraints:

SELECT tc.constraint_catalog, tc.constraint_schema, tc.constraint_name, tc.table_name, tc.constraint_type, tc.enforced
  FROM INFORMATION_SCHEMA.TABLE_CONSTRAINTS tc
    JOIN INFORMATION_SCHEMA.REFERENTIAL_CONSTRAINTS rc ON tc.constraint_name=rc.constraint_name;
Copy
+--------------------+-------------------+-----------------------------------------------------+------------+-----------------+----------+
| CONSTRAINT_CATALOG | CONSTRAINT_SCHEMA | CONSTRAINT_NAME                                     | TABLE_NAME | CONSTRAINT_TYPE | ENFORCED |
|--------------------+-------------------+-----------------------------------------------------+------------+-----------------+----------|
| HTABLES_DB         | HTABLES_SCHEMA    | SYS_CONSTRAINT_51118aaf-1ee6-4548-bc9a-f87e65d92528 | HTFK       | FOREIGN KEY     | YES      |
| HTABLES_DB         | HTABLES_SCHEMA    | SYS_CONSTRAINT_c97bfe9b-6098-4b8a-b796-e341071db72a | HT619      | FOREIGN KEY     | YES      |
+--------------------+-------------------+-----------------------------------------------------+------------+-----------------+----------+
Language: English