Don't recommend "DROP SCHEMA information_schema CASCADE".

It drops objects outside information_schema that depend on objects
inside information_schema.  For example, it will drop a user-defined
view if the view query refers to information_schema.

Discussion: https://postgr.es/m/20170831025345.GE3963697@rfd.leadboat.com
This commit is contained in:
Noah Misch 2017-09-26 22:39:44 -07:00
parent 9d0d0fe57c
commit 6525a3a709
1 changed files with 37 additions and 7 deletions

View File

@ -58,14 +58,44 @@
in an existing installation, you can, as a superuser, do this
in <application>psql</>:
<programlisting>
BEGIN;
DROP SCHEMA information_schema CASCADE;
\i <replaceable>SHAREDIR</>/information_schema.sql
COMMIT;
SET search_path TO information_schema;
CREATE OR REPLACE VIEW table_privileges AS
SELECT CAST(u_grantor.rolname AS sql_identifier) AS grantor,
CAST(grantee.rolname AS sql_identifier) AS grantee,
CAST(current_database() AS sql_identifier) AS table_catalog,
CAST(nc.nspname AS sql_identifier) AS table_schema,
CAST(c.relname AS sql_identifier) AS table_name,
CAST(c.prtype AS character_data) AS privilege_type,
CAST(
CASE WHEN
-- object owner always has grant options
pg_has_role(grantee.oid, c.relowner, 'USAGE')
OR c.grantable
THEN 'YES' ELSE 'NO' END AS yes_or_no) AS is_grantable,
CAST(CASE WHEN c.prtype = 'SELECT' THEN 'YES' ELSE 'NO' END AS yes_or_no) AS with_hierarchy
FROM (
SELECT oid, relname, relnamespace, relkind, relowner, (aclexplode(coalesce(relacl, acldefault('r', relowner)))).* FROM pg_class
) AS c (oid, relname, relnamespace, relkind, relowner, grantor, grantee, prtype, grantable),
pg_namespace nc,
pg_authid u_grantor,
(
SELECT oid, rolname FROM pg_authid
UNION ALL
SELECT 0::oid, 'PUBLIC'
) AS grantee (oid, rolname)
WHERE c.relnamespace = nc.oid
AND c.relkind IN ('r', 'v', 'f')
AND c.grantee = grantee.oid
AND c.grantor = u_grantor.oid
AND c.prtype IN ('INSERT', 'SELECT', 'UPDATE', 'DELETE', 'TRUNCATE', 'REFERENCES', 'TRIGGER')
AND (pg_has_role(u_grantor.oid, 'USAGE')
OR pg_has_role(grantee.oid, 'USAGE')
OR grantee.rolname = 'PUBLIC');
</programlisting>
(Run <literal>pg_config --sharedir</> if you're uncertain
where <replaceable>SHAREDIR</> is.) This must be repeated in each
database to be fixed.
This must be repeated in each database to be fixed,
including <literal>template0</>.
</para>
</listitem>