Skip to content

Commit

Permalink
[PRIMARY_KEYS_WITH_SERIAL_TYPES] ERROR: permission denied for schema (#…
Browse files Browse the repository at this point in the history
…62)

* Fix for primary_keys_with_serial_types.sql

* Fix linter warnings

* Fix linter warnings #2

* Fix error
  • Loading branch information
mfvanek authored Dec 9, 2024
1 parent 6db61f7 commit 1ff7b1c
Show file tree
Hide file tree
Showing 9 changed files with 106 additions and 70 deletions.
3 changes: 2 additions & 1 deletion sql/btree_indexes_on_array_columns.sql
Original file line number Diff line number Diff line change
Expand Up @@ -9,6 +9,7 @@
--
-- GIN-index should be used instead for such columns
-- Based on query from https://habr.com/ru/articles/800121/
-- See also https://www.postgresql.org/docs/current/catalog-pg-type.html#CATALOG-TYPCATEGORY-TABLE
select
i.indrelid::regclass::text as table_name,
i.indexrelid::regclass::text as index_name,
Expand All @@ -23,5 +24,5 @@ from pg_catalog.pg_index i
inner join pg_catalog.pg_type typ on typ.oid = col.atttypid
where
nsp.nspname = :schema_name_param::text and
typ.typcategory = 'A' -- A stands for Array type. See - https://www.postgresql.org/docs/current/catalog-pg-type.html#CATALOG-TYPCATEGORY-TABLE
typ.typcategory = 'A' /* A stands for Array type */
order by table_name, index_name;
81 changes: 49 additions & 32 deletions sql/columns_with_serial_types.sql
Original file line number Diff line number Diff line change
Expand Up @@ -9,38 +9,55 @@
-- that are not primary keys (or primary and foreign keys at the same time).
--
-- Based on https://dba.stackexchange.com/questions/90555/postgresql-select-primary-key-as-serial-or-bigserial/
select
col.attrelid::regclass::text as table_name,
col.attname::text as column_name,
col.attnotnull as column_not_null,
case col.atttypid
when 'int'::regtype then 'serial'
when 'int8'::regtype then 'bigserial'
when 'int2'::regtype then 'smallserial'
end as column_type,
pg_get_serial_sequence(col.attrelid::regclass::text, col.attname) as sequence_name
from
pg_catalog.pg_class t
inner join pg_catalog.pg_namespace nsp on nsp.oid = t.relnamespace
inner join pg_catalog.pg_attribute col on col.attrelid = t.oid
inner join pg_attrdef ad on ad.adrelid = col.attrelid and ad.adnum = col.attnum
left join lateral (
select sum(case when c.contype = 'p' then +1 else -1 end) as res
from pg_constraint c
with
t as (
select
col.attrelid::regclass::text as table_name,
col.attname::text as column_name,
col.attnotnull as column_not_null,
nsp.nspname as schema_name,
case col.atttypid
when 'int'::regtype then 'serial'
when 'int8'::regtype then 'bigserial'
when 'int2'::regtype then 'smallserial'
end as column_type,
pg_get_expr(ad.adbin, ad.adrelid) as column_default_value,
case
when has_schema_privilege(nsp.oid, 'create,usage'::text) then pg_get_serial_sequence(col.attrelid::regclass::text, col.attname)
else null::text
end as sequence_name
from
pg_catalog.pg_class t
inner join pg_catalog.pg_namespace nsp on nsp.oid = t.relnamespace
inner join pg_catalog.pg_attribute col on col.attrelid = t.oid
inner join pg_attrdef ad on ad.adrelid = col.attrelid and ad.adnum = col.attnum
left join lateral (
select sum(case when c.contype = 'p' then +1 else -1 end) as res
from pg_constraint c
where
c.conrelid = col.attrelid and
c.conkey[1] = col.attnum and
c.contype in ('p', 'f') and /* primary or foreign key */
array_length(c.conkey, 1) = 1 /* single column */
group by c.conrelid, c.conkey[1]
) c on true
where
c.conrelid = col.attrelid and
c.conkey[1] = col.attnum and
c.contype in ('p', 'f') and /* primary or foreign key */
array_length(c.conkey, 1) = 1 /* single column */
group by c.conrelid, c.conkey[1]
) c on true
t.relkind = 'r' and
col.attnum > 0 and /* to filter out system columns such as oid, ctid, xmin, xmax, etc. */
not col.attisdropped and
col.atttypid = any('{int,int8,int2}'::regtype[]) and
(c.res is null or c.res <= 0) and
nsp.nspname = :schema_name_param::text
)

select
table_name,
column_name,
column_not_null,
column_type,
case when schema_name = 'public'::text then replace(sequence_name, 'public.', '') else sequence_name end as sequence_name
from t
where
t.relkind = 'r' and
col.attnum > 0 and /* to filter out system columns such as oid, ctid, xmin, xmax, etc. */
not col.attisdropped and
col.atttypid = any('{int,int8,int2}'::regtype[]) and
(c.res is null or c.res <= 0) and
/* column default value = nextval from owned sequence */
pg_get_expr(ad.adbin, ad.adrelid) = 'nextval(''' || (pg_get_serial_sequence(col.attrelid::regclass::text, col.attname))::regclass || '''::regclass)' and
nsp.nspname = :schema_name_param::text
sequence_name is not null and
column_default_value = 'nextval(''' || sequence_name::regclass || '''::regclass)'
order by table_name, column_name;
2 changes: 1 addition & 1 deletion sql/duplicated_foreign_keys.sql
Original file line number Diff line number Diff line change
Expand Up @@ -46,7 +46,7 @@ select
from
fk_with_attributes_grouped c1
inner join fk_with_attributes_grouped c2
on c2.constraint_name > c1.constraint_name and -- to prevent duplicated rows in output
on c2.constraint_name > c1.constraint_name and /* to prevent duplicated rows in output */
c2.table_oid = c1.table_oid and
c2.foreign_table_oid = c1.foreign_table_oid and
c2.columns = c1.columns
Expand Down
2 changes: 1 addition & 1 deletion sql/duplicated_indexes.sql
Original file line number Diff line number Diff line change
Expand Up @@ -12,7 +12,7 @@ select
from (
select
x.indexrelid::regclass as idx,
x.indrelid::regclass::text as table_name, -- cast to text for sorting purposes
x.indrelid::regclass::text as table_name, /* cast to text for sorting purposes */
(
x.indrelid::text || ' ' || x.indclass::text || ' ' || x.indkey::text || ' ' ||
x.indcollation::text || ' ' ||
Expand Down
2 changes: 1 addition & 1 deletion sql/indexes_with_null_values.sql
Original file line number Diff line number Diff line change
Expand Up @@ -9,7 +9,7 @@
select
x.indrelid::regclass::text as table_name,
x.indexrelid::regclass::text as index_name,
string_agg(a.attname, ', ') as nullable_fields, -- In fact, there will always be only one column.
string_agg(a.attname, ', ') as nullable_fields, /* in fact, there will always be only one column */
pg_relation_size(x.indexrelid) as index_size
from
pg_catalog.pg_index x
Expand Down
6 changes: 3 additions & 3 deletions sql/intersected_foreign_keys.sql
Original file line number Diff line number Diff line change
Expand Up @@ -46,10 +46,10 @@ select
from
fk_with_attributes_grouped c1
inner join fk_with_attributes_grouped c2
on c2.constraint_name > c1.constraint_name and -- to prevent duplicated rows in output
on c2.constraint_name > c1.constraint_name and /* to prevent duplicated rows in output */
c2.table_oid = c1.table_oid and
c2.foreign_table_oid = c1.foreign_table_oid and
c2.columns && c1.columns -- arrays overlap/have any elements in common?
c2.columns && c1.columns /* arrays overlap/have any elements in common? */
where
c2.columns != c1.columns -- skip full duplicates
c2.columns != c1.columns /* skip full duplicates */
order by table_name, c1.constraint_name, c2.constraint_name;
12 changes: 6 additions & 6 deletions sql/not_valid_constraints.sql
Original file line number Diff line number Diff line change
Expand Up @@ -9,14 +9,14 @@
--
-- Based on query from https://habr.com/ru/articles/800121/
select
c.conrelid::regclass::text as table_name, -- Name of the table
c.conname as constraint_name, -- Name of the constraint
c.contype as constraint_type -- Type of the constraint
c.conrelid::regclass::text as table_name,
c.conname as constraint_name,
c.contype as constraint_type
from
pg_catalog.pg_constraint c
inner join pg_catalog.pg_namespace nsp on nsp.oid = c.connamespace
where
not c.convalidated and -- Constraints that have not yet been validated
c.contype in ('c', 'f') and -- Focus on check and foreign key constraints
nsp.nspname = :schema_name_param::text -- Make the query schema-aware
not c.convalidated and /* constraints that have not yet been validated */
c.contype in ('c', 'f') and /* focus on check and foreign key constraints */
nsp.nspname = :schema_name_param::text
order by table_name, c.conname;
58 changes: 38 additions & 20 deletions sql/primary_keys_with_serial_types.sql
Original file line number Diff line number Diff line change
Expand Up @@ -11,26 +11,44 @@
-- Based on https://dba.stackexchange.com/questions/90555/postgresql-select-primary-key-as-serial-or-bigserial/
-- See also https://wiki.postgresql.org/wiki/Don't_Do_This#Don.27t_use_serial
-- and https://stackoverflow.com/questions/55300370/postgresql-serial-vs-identity
with
t as (
select
col.attrelid::regclass::text as table_name,
col.attname::text as column_name,
col.attnotnull as column_not_null,
nsp.nspname as schema_name,
case col.atttypid
when 'int'::regtype then 'serial'
when 'int8'::regtype then 'bigserial'
when 'int2'::regtype then 'smallserial'
end as column_type,
pg_get_expr(ad.adbin, ad.adrelid) as column_default_value,
case
when has_schema_privilege(nsp.oid, 'create,usage'::text) then pg_get_serial_sequence(col.attrelid::regclass::text, col.attname)
else null::text
end as sequence_name
from
pg_catalog.pg_class t
inner join pg_catalog.pg_namespace nsp on nsp.oid = t.relnamespace
inner join pg_catalog.pg_attribute col on col.attrelid = t.oid
inner join pg_catalog.pg_attrdef ad on ad.adrelid = col.attrelid and ad.adnum = col.attnum
inner join pg_catalog.pg_constraint c on c.conrelid = col.attrelid and col.attnum = any(c.conkey)
where
col.atttypid = any('{int,int8,int2}'::regtype[]) and
not col.attisdropped and
c.contype = 'p' and /* primary keys */
nsp.nspname = :schema_name_param::text
)

select
col.attrelid::regclass::text as table_name,
col.attname::text as column_name,
col.attnotnull as column_not_null,
case col.atttypid
when 'int'::regtype then 'serial'
when 'int8'::regtype then 'bigserial'
when 'int2'::regtype then 'smallserial'
end as column_type,
pg_get_serial_sequence(col.attrelid::regclass::text, col.attname) as sequence_name
from
pg_catalog.pg_class t
inner join pg_catalog.pg_namespace nsp on nsp.oid = t.relnamespace
inner join pg_catalog.pg_attribute col on col.attrelid = t.oid
inner join pg_catalog.pg_attrdef ad on ad.adrelid = col.attrelid and ad.adnum = col.attnum
inner join pg_catalog.pg_constraint c on c.conrelid = col.attrelid and col.attnum = any(c.conkey)
table_name,
column_name,
column_not_null,
column_type,
case when schema_name = 'public'::text then replace(sequence_name, 'public.', '') else sequence_name end as sequence_name
from t
where
col.atttypid = any('{int,int8,int2}'::regtype[]) and
not col.attisdropped and
c.contype = 'p' and -- primary keys
pg_get_expr(ad.adbin, ad.adrelid) = 'nextval(''' || pg_get_serial_sequence(col.attrelid::regclass::text, col.attname)::regclass || '''::regclass)' and
nsp.nspname = :schema_name_param::text
sequence_name is not null and
column_default_value = 'nextval(''' || sequence_name::regclass || '''::regclass)'
order by table_name, column_name;
10 changes: 5 additions & 5 deletions sql/sequence_overflow.sql
Original file line number Diff line number Diff line change
Expand Up @@ -26,9 +26,9 @@ with
inner join pg_catalog.pg_class c on c.oid = s.seqrelid
left join pg_catalog.pg_namespace nsp on nsp.oid = c.relnamespace
where
not pg_is_other_temp_schema(nsp.oid) and -- not temporary
c.relkind = 'S'::char and -- sequence object
not s.seqcycle and -- skip cycle sequences
not pg_is_other_temp_schema(nsp.oid) and /* not temporary */
c.relkind = 'S'::char and /* sequence object */
not s.seqcycle and /* skip cycle sequences */
nsp.nspname = :schema_name_param::text
),

Expand All @@ -37,10 +37,10 @@ with
t.sequence_name,
t.data_type,
case
-- ascending or descending sequence
/* ascending or descending sequence */
when t.increment_by > 0 then 100.0 * (t.max_value - coalesce(t.last_value, t.start_value)) / (t.max_value - t.min_value)
else 100.0 * (coalesce(t.last_value, t.start_value) - t.min_value) / (t.max_value - t.min_value)
end ::numeric(5, 2) as remaining_percentage -- percentage of remaining values
end ::numeric(5, 2) as remaining_percentage /* percentage of remaining values */
from all_sequences t
)

Expand Down

0 comments on commit 1ff7b1c

Please sign in to comment.