Update information_schema definition for not-null constraints

Now that we have catalogued not-null constraints, our information_schema
definition can be updated to grab those rather than fabricate synthetic
definitions.

Note that we still don't have catalog rows for not-null constraints on
domains, but we've never had not-null constraints listed in
information_schema, so that's a problem to be solved separately.

Co-authored-by: Peter Eisentraut <peter.eisentraut@enterprisedb.com>
Co-authored-by: Álvaro Herrera <alvherre@alvh.no-ip.org>
Discussion: https://postgr.es/m/81b461c4-edab-5d8c-2f88-203108425340@enterprisedb.com
Discussion: https://postgr.es/m/202309041710.psytrxlsiqex@alvherre.pgsql
This commit is contained in:
Alvaro Herrera 2023-09-07 11:33:01 +02:00
parent e1c6db6309
commit 3af7217942
No known key found for this signature in database
GPG Key ID: 1C20ACB9D5C564AE
2 changed files with 28 additions and 48 deletions

View File

@ -444,22 +444,19 @@ CREATE VIEW check_constraints AS
WHERE pg_has_role(coalesce(c.relowner, t.typowner), 'USAGE') WHERE pg_has_role(coalesce(c.relowner, t.typowner), 'USAGE')
AND con.contype = 'c' AND con.contype = 'c'
UNION UNION ALL
-- not-null constraints -- not-null constraints
SELECT current_database()::information_schema.sql_identifier AS constraint_catalog,
SELECT CAST(current_database() AS sql_identifier) AS constraint_catalog, rs.nspname::information_schema.sql_identifier AS constraint_schema,
CAST(n.nspname AS sql_identifier) AS constraint_schema, con.conname::information_schema.sql_identifier AS constraint_name,
CAST(CAST(n.oid AS text) || '_' || CAST(r.oid AS text) || '_' || CAST(a.attnum AS text) || '_not_null' AS sql_identifier) AS constraint_name, -- XXX pg_catalog.format('CHECK (%s IS NOT NULL)', at.attname)::information_schema.character_data AS check_clause
CAST(a.attname || ' IS NOT NULL' AS character_data) FROM pg_constraint con
AS check_clause LEFT JOIN pg_namespace rs ON rs.oid = con.connamespace
FROM pg_namespace n, pg_class r, pg_attribute a LEFT JOIN pg_class c ON c.oid = con.conrelid
WHERE n.oid = r.relnamespace LEFT JOIN pg_type t ON t.oid = con.contypid
AND r.oid = a.attrelid LEFT JOIN pg_attribute at ON (con.conrelid = at.attrelid AND con.conkey[1] = at.attnum)
AND a.attnum > 0 WHERE pg_has_role(coalesce(c.relowner, t.typowner), 'USAGE'::text)
AND NOT a.attisdropped AND con.contype = 'n';
AND a.attnotnull
AND r.relkind IN ('r', 'p')
AND pg_has_role(r.relowner, 'USAGE');
GRANT SELECT ON check_constraints TO PUBLIC; GRANT SELECT ON check_constraints TO PUBLIC;
@ -826,6 +823,20 @@ CREATE VIEW constraint_column_usage AS
AND r.relkind IN ('r', 'p') AND r.relkind IN ('r', 'p')
AND NOT a.attisdropped AND NOT a.attisdropped
UNION ALL
/* not-null constraints */
SELECT DISTINCT nr.nspname, r.relname, r.relowner, a.attname, nc.nspname, c.conname
FROM pg_namespace nr, pg_class r, pg_attribute a, pg_namespace nc, pg_constraint c
WHERE nr.oid = r.relnamespace
AND r.oid = a.attrelid
AND r.oid = c.conrelid
AND a.attnum = c.conkey[1]
AND c.connamespace = nc.oid
AND c.contype = 'n'
AND r.relkind in ('r', 'p')
AND not a.attisdropped
UNION ALL UNION ALL
/* unique/primary key/foreign key constraints */ /* unique/primary key/foreign key constraints */
@ -1828,6 +1839,7 @@ CREATE VIEW table_constraints AS
CAST(r.relname AS sql_identifier) AS table_name, CAST(r.relname AS sql_identifier) AS table_name,
CAST( CAST(
CASE c.contype WHEN 'c' THEN 'CHECK' CASE c.contype WHEN 'c' THEN 'CHECK'
WHEN 'n' THEN 'CHECK'
WHEN 'f' THEN 'FOREIGN KEY' WHEN 'f' THEN 'FOREIGN KEY'
WHEN 'p' THEN 'PRIMARY KEY' WHEN 'p' THEN 'PRIMARY KEY'
WHEN 'u' THEN 'UNIQUE' END WHEN 'u' THEN 'UNIQUE' END
@ -1852,38 +1864,6 @@ CREATE VIEW table_constraints AS
AND c.contype NOT IN ('t', 'x') -- ignore nonstandard constraints AND c.contype NOT IN ('t', 'x') -- ignore nonstandard constraints
AND r.relkind IN ('r', 'p') AND r.relkind IN ('r', 'p')
AND (NOT pg_is_other_temp_schema(nr.oid)) AND (NOT pg_is_other_temp_schema(nr.oid))
AND (pg_has_role(r.relowner, 'USAGE')
-- SELECT privilege omitted, per SQL standard
OR has_table_privilege(r.oid, 'INSERT, UPDATE, DELETE, TRUNCATE, REFERENCES, TRIGGER')
OR has_any_column_privilege(r.oid, 'INSERT, UPDATE, REFERENCES') )
UNION ALL
-- not-null constraints
SELECT CAST(current_database() AS sql_identifier) AS constraint_catalog,
CAST(nr.nspname AS sql_identifier) AS constraint_schema,
CAST(CAST(nr.oid AS text) || '_' || CAST(r.oid AS text) || '_' || CAST(a.attnum AS text) || '_not_null' AS sql_identifier) AS constraint_name, -- XXX
CAST(current_database() AS sql_identifier) AS table_catalog,
CAST(nr.nspname AS sql_identifier) AS table_schema,
CAST(r.relname AS sql_identifier) AS table_name,
CAST('CHECK' AS character_data) AS constraint_type,
CAST('NO' AS yes_or_no) AS is_deferrable,
CAST('NO' AS yes_or_no) AS initially_deferred,
CAST('YES' AS yes_or_no) AS enforced,
CAST(NULL AS yes_or_no) AS nulls_distinct
FROM pg_namespace nr,
pg_class r,
pg_attribute a
WHERE nr.oid = r.relnamespace
AND r.oid = a.attrelid
AND a.attnotnull
AND a.attnum > 0
AND NOT a.attisdropped
AND r.relkind IN ('r', 'p')
AND (NOT pg_is_other_temp_schema(nr.oid))
AND (pg_has_role(r.relowner, 'USAGE') AND (pg_has_role(r.relowner, 'USAGE')
-- SELECT privilege omitted, per SQL standard -- SELECT privilege omitted, per SQL standard
OR has_table_privilege(r.oid, 'INSERT, UPDATE, DELETE, TRUNCATE, REFERENCES, TRIGGER') OR has_table_privilege(r.oid, 'INSERT, UPDATE, DELETE, TRUNCATE, REFERENCES, TRIGGER')

View File

@ -57,6 +57,6 @@
*/ */
/* yyyymmddN */ /* yyyymmddN */
#define CATALOG_VERSION_NO 202308251 #define CATALOG_VERSION_NO 202309061
#endif #endif