-
Notifications
You must be signed in to change notification settings - Fork 144
/
pg_stat_user_tables_usage.sql
47 lines (47 loc) · 2.2 KB
/
pg_stat_user_tables_usage.sql
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
--Как узнать, какие самые частые действия в таблице совершаются (чтение, добавление, обновление, удаление)?
with s1 as (
select
t.schemaname,
t.relname,
relid::regclass as table_name,
--pg_size_pretty(pg_relation_size(relid)),
--(select spcname from pg_tablespace where oid=(select dattablespace from pg_database where datname=current_database())) as table_space,
--seq_scan,
seq_tup_read + idx_tup_fetch as readed,
--idx_scan,
n_tup_ins as inserted,
n_tup_upd as updated,
n_tup_del as deleted,
--coalesce(n_tup_ins, 0) + 2 * coalesce(n_tup_upd, 0) - coalesce(n_tup_hot_upd, 0) + coalesce(n_tup_del, 0) as modified_total,
n_tup_ins + n_tup_upd + n_tup_del as modified,
n_tup_hot_upd * 100 / nullif(n_tup_upd, 0) as hot_updated_percent,
(regexp_match(c.reloptions::text, 'fillfactor=(\d+)', 'i'))[1] as fillfactor
from pg_stat_user_tables as t --https://postgrespro.ru/docs/postgresql/12/monitoring-stats
join pg_class as c on c.oid = t.relid
)
, s2 as (
select
*,
inserted * 100 / nullif(modified, 0) as inserted_percent,
updated * 100 / nullif(modified, 0) as updated_percent,
deleted * 100 / nullif(modified, 0) as deleted_percent,
round(modified::numeric * 100 / nullif(readed + modified, 0), 2) as modified_percent
from s1
)
, s3 as (
select
*,
concat_ws('+',
case when modified_percent < 20 then 'S' when modified_percent < 50 then 's' end, --select
case when inserted_percent > 90 then 'I' when inserted_percent > 30 then 'i' end, --insert
case when updated_percent > 90 then 'U' when updated_percent > 30 then 'u' end, --update
case when deleted_percent > 90 then 'D' when deleted_percent > 30 then 'd' end --delete
) as usage
from s2
)
select *
from s3
--where readed > 1e6 --пропускаем таблицы, у которых мало чтений
--and modified > 1e6 --пропускаем таблицы, у которых мало модификаций
order by modified_percent desc nulls last
limit 1000;