Last active
September 20, 2021 22:54
-
-
Save filiperdt/17b3dccfe5cf69eedb3478c1d7e70ca3 to your computer and use it in GitHub Desktop.
Listar todas as constraints, no PostgreSQL. Os resultados são ordenados por schema e table. A coluna "constraint_type" pode ser: p - chave primária, f - chave estrangeira, u - único, c - restrição de verificação, x - exclusão, ...
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
SELECT c.conname AS constraint_name, | |
c.contype AS constraint_type, | |
sch.nspname AS "self_schema", | |
tbl.relname AS "self_table", | |
ARRAY_AGG(col.attname ORDER BY u.attposition) AS "self_columns", | |
f_sch.nspname AS "foreign_schema", | |
f_tbl.relname AS "foreign_table", | |
ARRAY_AGG(f_col.attname ORDER BY f_u.attposition) AS "foreign_columns", | |
pg_get_constraintdef(c.oid) AS definition | |
FROM pg_constraint c | |
LEFT JOIN LATERAL UNNEST(c.conkey) WITH ORDINALITY AS u(attnum, attposition) ON TRUE | |
LEFT JOIN LATERAL UNNEST(c.confkey) WITH ORDINALITY AS f_u(attnum, attposition) ON f_u.attposition = u.attposition | |
JOIN pg_class tbl ON tbl.oid = c.conrelid | |
JOIN pg_namespace sch ON sch.oid = tbl.relnamespace | |
LEFT JOIN pg_attribute col ON (col.attrelid = tbl.oid AND col.attnum = u.attnum) | |
LEFT JOIN pg_class f_tbl ON f_tbl.oid = c.confrelid | |
LEFT JOIN pg_namespace f_sch ON f_sch.oid = f_tbl.relnamespace | |
LEFT JOIN pg_attribute f_col ON (f_col.attrelid = f_tbl.oid AND f_col.attnum = f_u.attnum) | |
GROUP BY constraint_name, constraint_type, "self_schema", "self_table", definition, "foreign_schema", "foreign_table" | |
ORDER BY "self_schema", "self_table"; |
Sign up for free
to join this conversation on GitHub.
Already have an account?
Sign in to comment