diff --git a/.pre-commit-config.yaml b/.pre-commit-config.yaml index 0b5f9cd..baaec26 100644 --- a/.pre-commit-config.yaml +++ b/.pre-commit-config.yaml @@ -42,6 +42,6 @@ repos: hooks: - id: black - repo: https://github.com/PyCQA/isort - rev: 5.10.1 + rev: 5.13.2 hooks: - id: isort diff --git a/pyproject.toml b/pyproject.toml index 3fe0463..6918bd6 100644 --- a/pyproject.toml +++ b/pyproject.toml @@ -24,9 +24,14 @@ isort = "5.10.1" migra = "*" black = "22.3.0" toml = "*" +pre-commit = "*" [tool.poetry.scripts] schemainspect = 'schemainspect:do_command' [tool.isort] profile = "black" + +[build-system] +requires = ["poetry-core>=1.0.0"] +build-backend = "poetry.core.masonry.api" diff --git a/schemainspect/command.py b/schemainspect/command.py index be06c5f..c4a9b66 100644 --- a/schemainspect/command.py +++ b/schemainspect/command.py @@ -30,11 +30,12 @@ def do_deps(db_url): deps = i.deps def process_row(dep): - depends_on = quoted_identifier(dep.name, dep.schema, dep.identity_arguments) + depends_on = quoted_identifier(dep.name, dep.schema, dep.identity_arguments, dep.result) thing = quoted_identifier( dep.name_dependent_on, dep.schema_dependent_on, dep.identity_arguments_dependent_on, + dep.result_dependent_on, ) return dict( diff --git a/schemainspect/inspected.py b/schemainspect/inspected.py index db89a14..124af96 100644 --- a/schemainspect/inspected.py +++ b/schemainspect/inspected.py @@ -6,6 +6,8 @@ class Inspected(AutoRepr): @property def quoted_full_name(self): + if self.schema == "": + return quoted_identifier(self.name) return quoted_identifier(self.name, schema=self.schema) @property diff --git a/schemainspect/misc.py b/schemainspect/misc.py index 26e16ca..d98117b 100644 --- a/schemainspect/misc.py +++ b/schemainspect/misc.py @@ -42,25 +42,25 @@ def __ne__(self, other): return not self == other -def unquoted_identifier(identifier, *, schema=None, identity_arguments=None): +def unquoted_identifier(identifier, *, schema=None, identity_arguments=None, return_type=None): if identifier is None and schema is not None: return schema s = "{}".format(identifier) if schema: s = "{}.{}".format(schema, s) if identity_arguments is not None: - s = "{}({})".format(s, identity_arguments) + s = "{}({}) RETURNS {}".format(s, identity_arguments, return_type) return s -def quoted_identifier(identifier, schema=None, identity_arguments=None): +def quoted_identifier(identifier, schema=None, identity_arguments=None, return_type=None): if identifier is None and schema is not None: return '"{}"'.format(schema.replace('"', '""')) s = '"{}"'.format(identifier.replace('"', '""')) if schema: s = '"{}".{}'.format(schema.replace('"', '""'), s) if identity_arguments is not None: - s = "{}({})".format(s, identity_arguments) + s = "{}({}) RETURNS {}".format(s, identity_arguments, return_type) return s diff --git a/schemainspect/pg/obj.py b/schemainspect/pg/obj.py index bc8639a..ceb0a0d 100644 --- a/schemainspect/pg/obj.py +++ b/schemainspect/pg/obj.py @@ -24,6 +24,7 @@ SEQUENCES_QUERY = resource_text("sql/sequences.sql") CONSTRAINTS_QUERY = resource_text("sql/constraints.sql") FUNCTIONS_QUERY = resource_text("sql/functions.sql") +AGG_FUNCTIONS_QUERY = resource_text("sql/agg_functions.sql") TYPES_QUERY = resource_text("sql/types.sql") DOMAINS_QUERY = resource_text("sql/domains.sql") EXTENSIONS_QUERY = resource_text("sql/extensions.sql") @@ -34,6 +35,7 @@ COLLATIONS_QUERY = resource_text("sql/collations.sql") COLLATIONS_QUERY_9 = resource_text("sql/collations9.sql") RLSPOLICIES_QUERY = resource_text("sql/rlspolicies.sql") +COMMENTS_QUERY = resource_text("sql/comments.sql") class InspectedSelectable(BaseInspectedSelectable): @@ -245,6 +247,7 @@ def __init__( strictness, security_type, identity_arguments, + function_arguments, result_string, language, full_definition, @@ -253,6 +256,7 @@ def __init__( kind, ): self.identity_arguments = identity_arguments + self.function_arguments = function_arguments self.result_string = result_string self.language = language self.volatility = volatility @@ -279,6 +283,10 @@ def returntype_is_table(self): @property def signature(self): + return "{}({})".format(self.quoted_full_name, self.function_arguments) + + @property + def identity_signature(self): return "{}({})".format(self.quoted_full_name, self.identity_arguments) @property @@ -303,12 +311,14 @@ def thing(self): @property def drop_statement(self): - return "drop {} if exists {};".format(self.thing, self.signature) + return "drop {} if exists {};".format(self.thing, self.identity_signature) def __eq__(self, other): return ( - self.signature == other.signature + self.identity_signature == other.identity_signature + and self.signature == other.signature and self.result_string == other.result_string + and self.returntype == other.returntype and self.definition == other.definition and self.language == other.language and self.volatility == other.volatility @@ -318,6 +328,102 @@ def __eq__(self, other): ) +class InspectedAggFunction(InspectedSelectable): + def __init__( + self, + object_type, + object_addr, + object_args, + schema, + name, + function_arguments, + function_identity_arguments, + aggtransfn, + aggfinalfn, + aggmtransfn, + aggmfinalfn, + aggtransspace, + agginitval, + aggminitval, + state_type, + ): + + self.object_type = object_type + self.object_addr = tuple(object_addr) + self.object_args = tuple(object_args) + self.schema = schema + self.name = name + self.function_arguments = function_arguments + self.function_identity_arguments = function_identity_arguments + + self.aggtransfn = aggtransfn + self.aggfinalfn = aggfinalfn + self.aggmtransfn = aggmtransfn + self.aggmfinalfn = aggmfinalfn + self.aggtransspace = aggtransspace + self.agginitval = agginitval + self.aggminitval = aggminitval + self.state_type = state_type + + super(InspectedAggFunction, self).__init__( + name=name, + schema=schema, + columns=None, + inputs=self.object_args, + definition="", + relationtype="a", + comment=None, + ) + + @property + def signature(self): + return "{}({})".format(self.quoted_full_name, self.function_arguments) + + @property + def identity_signature(self): + return "{}({})".format(self.quoted_full_name, self.function_identity_arguments) + + @property + def create_statement(self): + ddl = f"CREATE AGGREGATE {self.quoted_full_name} (" + + # Add arguments + ddl += f"{self.function_arguments}) (\n" + + # Add options + options = [] + if self.aggtransfn: + options.append(f" SFUNC = {self.aggtransfn}") + if self.aggfinalfn: + options.append(f" FINALFUNC = {self.aggfinalfn}") + if self.aggmtransfn: + options.append(f" MSFUNC = {self.aggmtransfn}") + if self.aggmfinalfn: + options.append(f" MFINALFUNC = {self.aggmfinalfn}") + if self.state_type: + options.append(f" STYPE = {self.state_type}") + if self.agginitval: + options.append(f" INITCOND = '{self.agginitval}'") + if self.aggminitval: + options.append(f" MINITCOND = '{self.aggminitval}'") + + ddl += ",\n".join(options) + ddl += "\n);" + + return ddl + + @property + def drop_statement(self): + return "drop aggregate if exists {};".format(self.identity_signature) + + def __eq__(self, other): + return ( + self.object_type == other.object_type + and self.object_addr == other.object_addr + and self.object_args == other.object_args + ) + + class InspectedTrigger(Inspected): def __init__( self, name, schema, table_name, proc_schema, proc_name, enabled, full_definition @@ -950,12 +1056,20 @@ def __eq__(self, other): class InspectedPrivilege(Inspected): - def __init__(self, object_type, schema, name, privilege, target_user): + def __init__(self, object_type, schema, name, privilege, target_user, postfix): self.schema = schema self.object_type = object_type self.name = name self.privilege = privilege.lower() self.target_user = target_user + self.postfix = postfix + + @property + def quoted_full_name(self): + full_name = super().quoted_full_name + if self.postfix: + full_name += self.postfix + return full_name @property def quoted_target_user(self): @@ -986,12 +1100,65 @@ def __eq__(self, other): self.name == other.name, self.privilege == other.privilege, self.target_user == other.target_user, + self.postfix == other.postfix, ) return all(equalities) @property def key(self): - return self.object_type, self.quoted_full_name, self.target_user, self.privilege + return ( + self.object_type, + self.quoted_full_name, + self.target_user, + self.privilege, + self.postfix, + ) + + +class InspectedComment(Inspected): + def __init__( + self, + object_type: str, + object_addr: list[str], + object_args: list[str], + comment, + object_description, + create_statement, + drop_statement, + ): + self.object_type = object_type + self.object_addr = tuple(object_addr) + self.object_args = tuple(object_args) + self.comment = comment + self.object_description = object_description + self._create_statement = create_statement + self._drop_statement = drop_statement + self.name = object_addr[-1] + self.schema = object_addr[0] + + @property + def quoted_full_name(self): + return self.object_description + + @property + def drop_statement(self): + return self._drop_statement + + @property + def create_statement(self): + return self._create_statement + + def __eq__(self, other): + equalities = ( + self.object_type == other.object_type, + self.object_addr == other.object_addr, + self.object_args == other.object_args, + ) + return all(equalities) + + @property + def key(self): + return self.object_type, self.object_addr, self.object_args RLS_POLICY_CREATE = """create policy {name} @@ -1073,7 +1240,7 @@ def __eq__(self, other): return all(equalities) -PROPS = "schemas relations tables views functions selectables sequences constraints indexes enums extensions privileges collations triggers rlspolicies" +PROPS = "schemas relations tables views functions aggregate_functions selectables sequences constraints indexes enums extensions privileges collations triggers rlspolicies" class PostgreSQL(DBInspector): @@ -1126,6 +1293,7 @@ def processed(q): self.SEQUENCES_QUERY = processed(SEQUENCES_QUERY) self.CONSTRAINTS_QUERY = processed(CONSTRAINTS_QUERY) self.FUNCTIONS_QUERY = processed(FUNCTIONS_QUERY) + self.AGG_FUNCTIONS_QUERY = processed(AGG_FUNCTIONS_QUERY) self.TYPES_QUERY = processed(TYPES_QUERY) self.DOMAINS_QUERY = processed(DOMAINS_QUERY) self.EXTENSIONS_QUERY = processed(EXTENSIONS_QUERY) @@ -1134,6 +1302,7 @@ def processed(q): self.SCHEMAS_QUERY = processed(SCHEMAS_QUERY) self.PRIVILEGES_QUERY = processed(PRIVILEGES_QUERY) self.TRIGGERS_QUERY = processed(TRIGGERS_QUERY) + self.COMMENTS_QUERY = processed(COMMENTS_QUERY) super(PostgreSQL, self).__init__(c, include_internal) @@ -1149,10 +1318,12 @@ def load_all(self): self.load_schemas() self.load_all_relations() self.load_functions() + self.load_aggregate_functions() self.selectables = od() self.selectables.update(self.relations) self.selectables.update(self.composite_types) self.selectables.update(self.functions) + self.selectables.update(self.aggregate_functions) self.load_privileges() self.load_triggers() @@ -1164,6 +1335,13 @@ def load_all(self): self.load_deps() self.load_deps_all() + self.load_comments() + + def load_comments(self): + q = self.execute(self.COMMENTS_QUERY) + comments = [InspectedComment(*each) for each in q] + self.comments = od((comment.key, comment) for comment in comments) + def load_schemas(self): q = self.execute(self.SCHEMAS_QUERY) schemas = [InspectedSchema(schema=each.schema) for each in q] @@ -1217,6 +1395,7 @@ def load_privileges(self): name=i.name, privilege=i.privilege, target_user=i.user, + postfix=i.postfix, ) for i in q ] @@ -1228,11 +1407,12 @@ def load_deps(self): self.deps = list(q) for dep in self.deps: - x = quoted_identifier(dep.name, dep.schema, dep.identity_arguments) + x = quoted_identifier(dep.name, dep.schema, dep.identity_arguments, dep.result) x_dependent_on = quoted_identifier( dep.name_dependent_on, dep.schema_dependent_on, dep.identity_arguments_dependent_on, + dep.result_dependent_on, ) self.selectables[x].dependent_on.append(x_dependent_on) self.selectables[x].dependent_on.sort() @@ -1600,6 +1780,7 @@ def load_functions(self): columns=od((c.name, c) for c in columns), inputs=plist, identity_arguments=f.identity_arguments, + function_arguments=f.function_arguments, result_string=f.result_string, language=f.language, definition=f.definition, @@ -1612,9 +1793,33 @@ def load_functions(self): kind=f.kind, ) - identity_arguments = "({})".format(s.identity_arguments) + identity_arguments = "({}) RETURNS {}".format(s.identity_arguments, s.result_string) self.functions[s.quoted_full_name + identity_arguments] = s + def load_aggregate_functions(self): + q = self.execute(self.AGG_FUNCTIONS_QUERY) + agg_functions = [ + InspectedAggFunction( + object_type=i.object_type, + object_addr=i.object_addr, + object_args=i.object_args, + schema=i.schema, + name=i.name, + function_arguments=i.function_arguments, + function_identity_arguments=i.function_identity_arguments, + aggtransfn=i.aggtransfn, + aggfinalfn=i.aggfinalfn, + aggmtransfn=i.aggmtransfn, + aggmfinalfn=i.aggmfinalfn, + aggtransspace=i.aggtransspace, + agginitval=i.agginitval, + aggminitval=i.aggminitval, + state_type=i.state_type, + ) + for i in q + ] + self.aggregate_functions = od((i.identity_signature, i) for i in agg_functions) + def load_triggers(self): q = self.execute(self.TRIGGERS_QUERY) triggers = [ @@ -1762,6 +1967,7 @@ def __eq__(self, other): and self.constraints == other.constraints and self.extensions == other.extensions and self.functions == other.functions + and self.agg_functions == other.agg_functions and self.triggers == other.triggers and self.collations == other.collations and self.rlspolicies == other.rlspolicies diff --git a/schemainspect/pg/sql/agg_functions.sql b/schemainspect/pg/sql/agg_functions.sql new file mode 100644 index 0000000..c57afeb --- /dev/null +++ b/schemainspect/pg/sql/agg_functions.sql @@ -0,0 +1,28 @@ +SELECT obj_address.type AS object_type + , obj_address.object_names AS object_addr + , obj_address.object_args AS object_args + , nsp.nspname AS schema + , p.proname AS name + , pg_catalog.PG_GET_FUNCTION_ARGUMENTS(p.oid) AS function_arguments + , pg_catalog.pg_get_function_identity_arguments(p.oid) AS function_identity_arguments + , pg_catalog.PG_GET_FUNCTION_RESULT(p.oid) AS result_type + , NULLIF(a.aggtransfn::TEXT, '-')::REGPROC AS aggtransfn + , NULLIF(a.aggfinalfn::TEXT, '-')::REGPROC AS aggfinalfn + , NULLIF(a.aggmtransfn::TEXT, '-')::REGPROC AS aggmtransfn + , NULLIF(a.aggmfinalfn::TEXT, '-')::REGPROC AS aggmfinalfn + , a.aggtransspace AS aggtransspace + , a.aggmtransspace AS aggmtransspace + , a.agginitval AS agginitval + , a.aggminitval AS aggminitval + , a.aggkind AS aggkind + , a.aggnumdirectargs AS aggnumdirectargs + , tt.oid::REGTYPE AS state_type + , ttf.oid::REGTYPE AS final_type +FROM pg_catalog.pg_proc p +JOIN LATERAL PG_IDENTIFY_OBJECT_AS_ADDRESS('pg_proc'::REGCLASS, p.oid, 0) AS obj_address ON TRUE +JOIN pg_catalog.pg_namespace nsp ON p.pronamespace = nsp.oid +JOIN pg_catalog.pg_aggregate a ON a.aggfnoid = p.oid +LEFT JOIN pg_catalog.pg_type tt ON tt.oid = a.aggtranstype +LEFT JOIN pg_catalog.pg_type ttf ON ttf.oid = p.prorettype +WHERE nsp.nspname NOT IN ('pg_catalog', 'information_schema') +ORDER BY schema, name; diff --git a/schemainspect/pg/sql/comments.sql b/schemainspect/pg/sql/comments.sql new file mode 100644 index 0000000..f5f5c8f --- /dev/null +++ b/schemainspect/pg/sql/comments.sql @@ -0,0 +1,45 @@ +SELECT obj_address.type AS object_type + , obj_address.object_names AS object_addr + , obj_address.object_args AS object_args + , d.description AS comment + , 'comment on ' || PG_DESCRIBE_OBJECT(d.classoid, d.objoid, d.objsubid) AS object_description + , CASE + WHEN obj_address.type = 'function' + THEN 'COMMENT ON FUNCTION ' || ARRAY_TO_STRING( + (SELECT ARRAY_AGG(QUOTE_IDENT(o)) FROM UNNEST(obj_address.object_names) o), '.') || '(' || + ARRAY_TO_STRING(object_args, ', ') || ') IS ' || QUOTE_LITERAL(d.description) || ';' + WHEN obj_address.type LIKE '% column' + THEN 'COMMENT ON COLUMN ' || + ARRAY_TO_STRING((SELECT ARRAY_AGG(QUOTE_IDENT(o)) FROM UNNEST(obj_address.object_names) o), '.') || + ' IS ' || QUOTE_LITERAL(d.description) || ';' + WHEN obj_address.type = 'type' + THEN 'COMMENT ON TYPE ' || + (SELECT QUOTE_IDENT(typnamespace::REGNAMESPACE::TEXT) || '.' || QUOTE_IDENT(typname) + FROM pg_type + WHERE oid = obj_address.object_names[1]::REGTYPE) || ' IS ' || QUOTE_LITERAL(d.description) || ';' + ELSE 'COMMENT ON ' || UPPER(obj_address.type) || ' ' || + ARRAY_TO_STRING((SELECT ARRAY_AGG(QUOTE_IDENT(o)) FROM UNNEST(obj_address.object_names) o), '.') || + ' IS ' || QUOTE_LITERAL(d.description) || ';' + END AS create_statement + , CASE + WHEN obj_address.type = 'function' + THEN 'COMMENT ON FUNCTION ' || + ARRAY_TO_STRING((SELECT ARRAY_AGG(QUOTE_IDENT(o)) FROM UNNEST(obj_address.object_names) o), '.') || + '(' || ARRAY_TO_STRING(object_args, ', ') || ') IS NULL;' + WHEN obj_address.type LIKE '% column' + THEN 'COMMENT ON COLUMN ' || + ARRAY_TO_STRING((SELECT ARRAY_AGG(QUOTE_IDENT(o)) FROM UNNEST(obj_address.object_names) o), '.') || + ' IS NULL;' + WHEN obj_address.type = 'type' + THEN 'COMMENT ON TYPE ' || + (SELECT QUOTE_IDENT(typnamespace::REGNAMESPACE::TEXT) || '.' || QUOTE_IDENT(typname) + FROM pg_type + WHERE oid = obj_address.object_names[1]::REGTYPE) || ' IS NULL;' + ELSE 'COMMENT ON ' || UPPER(obj_address.type) || ' ' || + ARRAY_TO_STRING((SELECT ARRAY_AGG(QUOTE_IDENT(o)) FROM UNNEST(obj_address.object_names) o), '.') || + ' IS NULL;' + END AS drop_statement +FROM pg_description d +JOIN LATERAL PG_IDENTIFY_OBJECT_AS_ADDRESS(d.classoid, d.objoid, d.objsubid) AS obj_address ON TRUE +WHERE obj_address.object_names[1] NOT LIKE 'pg_%' + AND obj_address.object_names[1] != 'information_schema'; diff --git a/schemainspect/pg/sql/deps.sql b/schemainspect/pg/sql/deps.sql index 09e8561..b621b3b 100644 --- a/schemainspect/pg/sql/deps.sql +++ b/schemainspect/pg/sql/deps.sql @@ -1,11 +1,12 @@ - with things1 as ( select oid as objid, pronamespace as namespace, proname as name, pg_get_function_identity_arguments(oid) as identity_arguments, - 'f' as kind + pg_get_function_result(oid) as result, + 'f' as kind, + null::oid as composite_type_oid from pg_proc -- 11_AND_LATER where pg_proc.prokind != 'a' -- 10_AND_EARLIER where pg_proc.proisagg is False @@ -15,11 +16,24 @@ with things1 as ( relnamespace as namespace, relname as name, null as identity_arguments, - relkind as kind + null as result, + relkind as kind, + null::oid as composite_type_oid from pg_class where oid not in ( select ftrelid from pg_foreign_table ) + union + select + oid, + typnamespace as namespace, + typname as name, + null as identity_arguments, + null as result, + 'c' as kind, + typrelid::oid as composite_type_oid + from pg_type + where typrelid != 0 ), extension_objids as ( select @@ -43,7 +57,9 @@ things as ( kind, n.nspname as schema, name, - identity_arguments + identity_arguments, + result, + t.composite_type_oid from things1 t inner join pg_namespace n on t.namespace = n.oid @@ -55,17 +71,30 @@ things as ( and nspname not like 'pg_temp_%' and nspname not like 'pg_toast_temp_%' and extension_objids.extension_objid is null ), +array_dependencies as ( + select + att.attrelid as objid, + att.attname as column_name, + tbl.typelem as composite_type_oid, + comp_tbl.typrelid as objid_dependent_on + from pg_attribute att + join pg_type tbl on tbl.oid = att.atttypid + join pg_type comp_tbl on tbl.typelem = comp_tbl.oid + where tbl.typcategory = 'A' +), combined as ( select distinct - t.objid, + coalesce(t.composite_type_oid, t.objid), t.schema, t.name, t.identity_arguments, - t.kind, + t.result, + case when t.composite_type_oid is not null then 'r' ELSE t.kind end, things_dependent_on.objid as objid_dependent_on, things_dependent_on.schema as schema_dependent_on, things_dependent_on.name as name_dependent_on, things_dependent_on.identity_arguments as identity_arguments_dependent_on, + things_dependent_on.result as result_dependent_on, things_dependent_on.kind as kind_dependent_on FROM pg_depend d @@ -80,8 +109,50 @@ combined as ( d.deptype in ('n') and rw.rulename = '_RETURN' + union all + select distinct + coalesce(t.composite_type_oid, t.objid), + t.schema, + t.name, + t.identity_arguments, + t.result, + case when t.composite_type_oid is not null then 'r' ELSE t.kind end, + things_dependent_on.objid as objid_dependent_on, + things_dependent_on.schema as schema_dependent_on, + things_dependent_on.name as name_dependent_on, + things_dependent_on.identity_arguments as identity_arguments_dependent_on, + things_dependent_on.result as result_dependent_on, + things_dependent_on.kind as kind_dependent_on + FROM + pg_depend d + inner join things things_dependent_on + on d.refobjid = things_dependent_on.objid + inner join things t + on d.objid = t.objid + where + d.deptype in ('n') + union all + select + coalesce(t.composite_type_oid, t.objid), + t.schema, + t.name, + t.identity_arguments, + t.result, + case when t.composite_type_oid is not null then 'r' ELSE t.kind end, + things_dependent_on.objid as objid_dependent_on, + things_dependent_on.schema as schema_dependent_on, + things_dependent_on.name as name_dependent_on, + things_dependent_on.identity_arguments as identity_arguments_dependent_on, + things_dependent_on.result as result_dependent_on, + things_dependent_on.kind as kind_dependent_on + FROM + array_dependencies ad + inner join things things_dependent_on + on ad.objid_dependent_on = things_dependent_on.objid + inner join things t + on ad.objid = t.objid ) select * from combined order by -schema, name, identity_arguments, kind_dependent_on, -schema_dependent_on, name_dependent_on, identity_arguments_dependent_on +schema, name, identity_arguments, result, kind_dependent_on, +schema_dependent_on, name_dependent_on, identity_arguments_dependent_on, result_dependent_on diff --git a/schemainspect/pg/sql/functions.sql b/schemainspect/pg/sql/functions.sql index 471de77..57ad9ab 100644 --- a/schemainspect/pg/sql/functions.sql +++ b/schemainspect/pg/sql/functions.sql @@ -207,6 +207,7 @@ unnested as ( p.extension_oid as extension_oid, pg_get_function_result(p.oid) as result_string, pg_get_function_identity_arguments(p.oid) as identity_arguments, + pg_get_function_arguments(p.oid) as function_arguments, pg_catalog.obj_description(p.oid) as comment FROM unnested p diff --git a/schemainspect/pg/sql/privileges.sql b/schemainspect/pg/sql/privileges.sql index f2198e0..43dc7ae 100644 --- a/schemainspect/pg/sql/privileges.sql +++ b/schemainspect/pg/sql/privileges.sql @@ -1,16 +1,75 @@ -select - table_schema as schema, - table_name as name, - 'table' as object_type, - grantee as user, - privilege_type as privilege -from information_schema.role_table_grants -where grantee != ( - select tableowner - from pg_tables - where schemaname = table_schema - and tablename = table_name +WITH partition_child_tables as ( + select + inhrelid + from + pg_inherits ) --- SKIP_INTERNAL and table_schema not in ('pg_internal', 'pg_catalog', 'information_schema', 'pg_toast') --- SKIP_INTERNAL and table_schema not like 'pg_temp_%' and table_schema not like 'pg_toast_temp_%' -order by schema, name, user; +select + n.nspname as schema, + c.relname as name, + case + when c.relkind in ('r', 'v', 'm', 'f', 'p') then 'table' + when c.relkind = 'S' then 'sequence' + else null end as object_type, + pg_get_userbyid(acl.grantee) as "user", + acl.privilege, + NULL as postfix +from + pg_catalog.pg_class c + join pg_catalog.pg_namespace n + on n.oid = c.relnamespace, + lateral (select aclx.*, privilege_type as privilege + from aclexplode(c.relacl) aclx + union + select aclx.*, privilege_type || '(' || a.attname || ')' as privilege + from + pg_catalog.pg_attribute a + cross join aclexplode(a.attacl) aclx + where attrelid = c.oid and not attisdropped and attacl is not null ) acl +where + acl.grantee != acl.grantor + and acl.grantee != 0 + and c.relkind in ('r', 'v', 'm', 'S', 'f', 'p') + -- and table is not a partition child table + and c.oid not in (select inhrelid from partition_child_tables) +-- SKIP_INTERNAL and nspname not in ('pg_internal', 'pg_catalog', 'information_schema', 'pg_toast') +-- SKIP_INTERNAL and nspname not like 'pg_temp_%' and nspname not like 'pg_toast_temp_%' +union +select + routine_schema as schema, + routine_name as name, + 'function' as object_type, + grantee as "user", + privilege_type as privilege, + FORMAT('(%s)', PG_GET_FUNCTION_IDENTITY_ARGUMENTS(oid)) as postfix + FROM information_schema.role_routine_grants g + JOIN pg_catalog.pg_proc p ON g.specific_schema::REGNAMESPACE = p.pronamespace::REGNAMESPACE AND g.specific_name = FORMAT('%s_%s', p.proname, p.oid) +where + grantor != grantee + and grantee != 'PUBLIC' +-- SKIP_INTERNAL and routine_schema not in ('pg_internal', 'pg_catalog', 'information_schema', 'pg_toast') +-- SKIP_INTERNAL and routine_schema not like 'pg_temp_%' and routine_schema not like 'pg_toast_temp_%' +union +select + '' as schema, + n.nspname as name, + 'schema' as object_type, + pg_get_userbyid(acl.grantee) as "user", + privilege, + NULL as postfix +from pg_catalog.pg_namespace n, + lateral (select aclx.*, privilege_type as privilege + from aclexplode(n.nspacl) aclx + union + select aclx.*, privilege_type || '(' || a.attname || ')' as privilege + from + pg_catalog.pg_attribute a + cross join aclexplode(a.attacl) aclx + where attrelid = n.oid and not attisdropped and attacl is not null ) acl +where + privilege != 'CREATE' + and acl.grantor != acl.grantee + and acl.grantee != 0 +-- SKIP_INTERNAL and n.nspname not in ('pg_internal', 'pg_catalog', 'information_schema', 'pg_toast') +-- SKIP_INTERNAL and n.nspname not like 'pg_temp_%' and n.nspname not like 'pg_toast_temp_%' +order by schema, name, "user"; diff --git a/schemainspect/pg/sql/relations.sql b/schemainspect/pg/sql/relations.sql index 92f5f94..2929a65 100644 --- a/schemainspect/pg/sql/relations.sql +++ b/schemainspect/pg/sql/relations.sql @@ -97,12 +97,12 @@ FROM r left join pg_catalog.pg_attribute a on r.oid = a.attrelid and a.attnum > 0 + and not a.attisdropped left join pg_catalog.pg_attrdef ad on a.attrelid = ad.adrelid and a.attnum = ad.adnum left join enums e on a.atttypid = e.enum_oid -where a.attisdropped is not true --- SKIP_INTERNAL and r.schema not in ('pg_catalog', 'information_schema', 'pg_toast') +-- SKIP_INTERNAL WHERE r.schema not in ('pg_catalog', 'information_schema', 'pg_toast') -- SKIP_INTERNAL and r.schema not like 'pg_temp_%' and r.schema not like 'pg_toast_temp_%' order by relationtype, r.schema, r.name, position_number; diff --git a/schemainspect/pg/sql/triggers.sql b/schemainspect/pg/sql/triggers.sql index 11ed062..40ce1cf 100644 --- a/schemainspect/pg/sql/triggers.sql +++ b/schemainspect/pg/sql/triggers.sql @@ -6,6 +6,12 @@ with extension_oids as ( WHERE d.refclassid = 'pg_extension'::regclass and d.classid = 'pg_trigger'::regclass +), +partition_child_tables as ( + select + inhrelid + from + pg_inherits ) select tg.tgname "name", @@ -22,5 +28,6 @@ join pg_namespace nsp on nsp.oid = cls.relnamespace join pg_proc proc on proc.oid = tg.tgfoid join pg_namespace nspp on nspp.oid = proc.pronamespace where not tg.tgisinternal + and cls.oid not in (select * from partition_child_tables) -- Exclude partition child tables -- SKIP_INTERNAL and not tg.oid in (select * from extension_oids) order by schema, table_name, name; diff --git a/tests/test_all.py b/tests/test_all.py index 89c66f8..892a0df 100644 --- a/tests/test_all.py +++ b/tests/test_all.py @@ -456,7 +456,7 @@ def asserts_pg(i, has_timescale=False): assert n("films_title_idx") in t.indexes # privileges - g = InspectedPrivilege("table", "public", "films", "select", "postgres") + g = InspectedPrivilege("table", "public", "films", "select", "postgres", None) g = i.privileges[g.key] assert g.create_statement == 'grant select on table {} to "postgres";'.format( t_films diff --git a/tests/test_privileges.py b/tests/test_privileges.py index 2368758..da9b989 100644 --- a/tests/test_privileges.py +++ b/tests/test_privileges.py @@ -2,13 +2,15 @@ def test_inspected_privilege(): - a = InspectedPrivilege("table", "public", "test_table", "select", "test_user") - a2 = InspectedPrivilege("table", "public", "test_table", "select", "test_user") + a = InspectedPrivilege("table", "public", "test_table", "select", "test_user", None) + a2 = InspectedPrivilege( + "table", "public", "test_table", "select", "test_user", None + ) b = InspectedPrivilege( - "function", "schema", "test_function", "execute", "test_user" + "function", "schema", "test_function", "execute", "test_user", "(int,int)" ) b2 = InspectedPrivilege( - "function", "schema", "test_function", "modify", "test_user" + "function", "schema", "test_function", "modify", "test_user", "(int,int)" ) assert a == a2 assert a == a @@ -16,10 +18,10 @@ def test_inspected_privilege(): assert b != b2 assert ( b2.create_statement - == 'grant modify on function "schema"."test_function" to "test_user";' + == 'grant modify on function "schema"."test_function"(int,int) to "test_user";' ) assert ( b.drop_statement - == 'revoke execute on function "schema"."test_function" from "test_user";' + == 'revoke execute on function "schema"."test_function"(int,int) from "test_user";' ) - assert a.key == ("table", '"public"."test_table"', "test_user", "select") + assert a.key == ("table", '"public"."test_table"', "test_user", "select", None)