Skip to content

Commit c939b6b

Browse files
authored
view db_audit.tables_from_unused_migration
1 parent 28638ca commit c939b6b

File tree

1 file changed

+44
-0
lines changed

1 file changed

+44
-0
lines changed

DDL_log_to_table/do.4_views.sql

Lines changed: 44 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -141,3 +141,47 @@ GRANT SELECT ON db_audit.ddl_objects TO alexan;
141141

142142
--TEST
143143
table db_audit.ddl_objects limit 100;
144+
145+
------------------------------------------------------------------------------------------------------------------------
146+
147+
CREATE VIEW db_audit.tables_from_unused_migration AS
148+
WITH t AS (
149+
SELECT n.nspname as schema_name,
150+
c.relname as table_name,
151+
pg_total_relation_size(c.oid) as total_size,
152+
(select reltuples::bigint
153+
from pg_class
154+
where oid = (n.nspname || '.' || c.relname)::regclass
155+
) as rows_estimate_count
156+
FROM pg_catalog.pg_class c,
157+
pg_catalog.pg_namespace n
158+
WHERE c.relnamespace = n.oid
159+
AND c.relkind = 'r'
160+
AND n.nspname IN ('migration', 'unused')
161+
)
162+
(SELECT
163+
t.schema_name,
164+
t.table_name,
165+
pg_size_pretty(t.total_size) AS pretty_total_size,
166+
regexp_replace(t.rows_estimate_count::text, '(?<=\d)(?<!\.[^.]*)(?=(\d\d\d)+(?!\d))', ',', 'g') AS pretty_rows_estimate_count,
167+
coalesce(o.updated_at, o.created_at) as table_modified_at
168+
FROM t
169+
INNER JOIN db_audit.ddl_objects as o on o.object_identity = t.schema_name || '.' || t.table_name
170+
ORDER BY schema_name, table_name desc)
171+
union all
172+
(select null,
173+
'*TOTAL*',
174+
pg_size_pretty(sum(t.total_size)),
175+
regexp_replace(sum(rows_estimate_count)::text, '(?<=\d)(?<!\.[^.]*)(?=(\d\d\d)+(?!\d))', ',', 'g'),
176+
null
177+
from t);
178+
179+
comment on view db_audit.tables_from_unused_migration is 'Список таблиц из схем unused и migration с размером занимаемого места, количеством строк и датой модификации в каждой таблице';
180+
181+
grant select on db_audit.tables_from_unused_migration to alexan;
182+
183+
-- TEST
184+
-- список таблиц, которые можно удалить
185+
select *
186+
from db_audit.tables_from_unused_migration
187+
where table_modified_at < now() - interval '2 week';

0 commit comments

Comments
 (0)